List dates outside specified date ranges
This article demonstrates how to calculate dates in a given date range (cells B13 and B14) that don't overlap the date ranges specified in cells A3:B10 (Excel Table).
Table of Contents
1. List dates outside specified date ranges
The Excel defined table contains start and end dates for each date range in cell range A3:B10. Cell B13 is the start date and B14 is the end date which are the outer boundaries, obviously, we can't list all dates that ever existed.
The array formula in cell B16 filters all dates between the start and end date and outside the specified date ranges in the Excel defined table.
I made a simple calendar (D3:AH10) next to the Excel defined table (A3:B10) that shows the date ranges and dates not in date ranges (red x). Row 2 contains the days in January 1 to 31, each x below rowĀ 2 represents a day in each date range. This makes it much easier to demonstrate and explain what the formula does and also verify the formula result.
Array formula in cell B16:
How to create an array formula
- Copy above array formula
- Press with left mouse button on in formula bar
- Paste array formula (Ctrl + v)
- Press and hold Ctrl + Shift
- Press Enter
How to copy array formula
- Select cell B16
- Copy cell (Ctrl + c)
- Select cell range B17:B25
- Paste (Ctrl + v)
Explaining formula in cell B16
Step 1 - Dynamic cell reference
The INDEX function creates a cell reference based on cell B14 - B13. This cell referenc will in a later step be used to create an array containing a sequence of numbers ranging from 0 to 29. If you change the dates in cell B13 or B14 a new sequence of values is instantly created.
$A$1:INDEX($A:$A,$B$14-$B$13)
becomes
$A$1:INDEX($A:$A,40939-40909)
becomes
$A$1:INDEX($A:$A,30)
and returns
$A$1:$A$30
Step 2 - Create a sequence and add a less than sign to each value in the array
"<="&$B$13+ROW($A$1:INDEX($A:$A,$B$14-$B$13))-1
becomes
"<="&$B$13+ROW($A$1:$A$30)-1
becomes
"<="&$B$13+{0; 1; 2; 3; 4; 5; 6; 7; 8; 9; 10; 11; 12; 13; 14; 15; 16; 17; 18; 19; 20; 21; 22; 23; 24; 25; 26; 27; 28; 29}
becomes
"<="&40909+{0; 1; 2; 3; 4; 5; 6; 7; 8; 9; 10; 11; 12; 13; 14; 15; 16; 17; 18; 19; 20; 21; 22; 23; 24; 25; 26; 27; 28; 29}
becomes
"<="&{40909; 40910; 40911; 40912; 40913; 40914; 40915; 40916; 40917; 40918; 40919; 40920; 40921; 40922; 40923; 40924; 40925; 40926; 40927; 40928; 40929; 40930; 40931; 40932; 40933; 40934; 40935; 40936; 40937; 40938}
and returns
{"<=40909"; "<=40910"; "<=40911"; "<=40912"; "<=40913"; "<=40914"; "<=40915"; "<=40916"; "<=40917"; "<=40918"; "<=40919"; "<=40920"; "<=40921"; "<=40922"; "<=40923"; "<=40924"; "<=40925"; "<=40926"; "<=40927"; "<=40928"; "<=40929"; "<=40930"; "<=40931"; "<=40932"; "<=40933"; "<=40934"; "<=40935"; "<=40936"; "<=40937"; "<=40938"}
Step 3 - Check if dynamic dates are inside the date ranges
The COUNTIFS function calculates the number of cells across multiple ranges that equals all given conditions. The date ranges has a start date and an end date, that means we need two conditions to check if dates are inside the date ranges. The only difference between these two conditions are the less than and greater than signs concatenated to each date.
COUNTIFS(Table1[Start:], "<="&$B$13+ROW($A$1:INDEX($A:$A, $B$14-$B$13))-1, Table1[End:], ">="&$B$13+ROW($A$1:INDEX($A:$A, $B$14-$B$13))-1)
returns
{0; 1; 1; 1; 1; 0; 1; 2; 2; 1; 1; 1; 1; 0; 0; 1; 2; 2; 2; 2; 1; 0; 0; 0; 1; 2; 2; 1; 2; 2}.
Step 4 - Replace 0 (zero) in array with corresponding date
TheĀ IF functionĀ has three arguments, the first one must be a logical expression. If the expression evaluates to TRUE then one thing happens (argument 2) and if FALSE another thing happens (argument 3).
IF(COUNTIFS(Table1[Start:], "<="&$B$13+ROW($A$1:INDEX($A:$A, $B$14-$B$13))-1, Table1[End:], ">="&$B$13+ROW($A$1:INDEX($A:$A, $B$14-$B$13))-1), "", $B$13+ROW($A$1:INDEX($A:$A, $B$14-$B$13))-1)
becomes
IF({0; 1; 1; 1; 1; 0; 1; 2; 2; 1; 1; 1; 1; 0; 0; 1; 2; 2; 2; 2; 1; 0; 0; 0; 1; 2; 2; 1; 2; 2}, "", {40909; 40910; 40911; 40912; 40913; 40914; 40915; 40916; 40917; 40918; 40919; 40920; 40921; 40922; 40923; 40924; 40925; 40926; 40927; 40928; 40929; 40930; 40931; 40932; 40933; 40934; 40935; 40936; 40937; 40938})
becomes
IF({0; 1; 1; 1; 1; 0; 1; 2; 2; 1; 1; 1; 1; 0; 0; 1; 2; 2; 2; 2; 1; 0; 0; 0; 1; 2; 2; 1; 2; 2}, "", $B$13+ROW($A$1:INDEX($A:$A, $B$14-$B$13))-1)
and returns
{40909; ""; ""; ""; ""; 40914; ""; ""; ""; ""; ""; ""; ""; 40922; 40923; ""; ""; ""; ""; ""; ""; 40930; 40931; 40932; ""; ""; ""; ""; ""; ""}
Step 5 - Extract k-th smallest date
To be able to return a new value in a cell each I use theĀ SMALL functionĀ to filter date numbers from smallest to larges
SMALL(IF(COUNTIFS(Table1[Start:], "<="&$B$13+ROW($A$1:INDEX($A:$A, $B$14-$B$13))-1, Table1[End:], ">="&$B$13+ROW($A$1:INDEX($A:$A, $B$14-$B$13))-1), "", $B$13+ROW($A$1:INDEX($A:$A, $B$14-$B$13))-1), ROW(A1))
becomes
SMALL({40909; ""; ""; ""; ""; 40914; ""; ""; ""; ""; ""; ""; ""; 40922; 40923; ""; ""; ""; ""; ""; ""; 40930; 40931; 40932; ""; ""; ""; ""; ""; ""}, ROW(A1))
becomes
SMALL({40909; ""; ""; ""; ""; 40914; ""; ""; ""; ""; ""; ""; ""; 40922; 40923; ""; ""; ""; ""; ""; ""; 40930; 40931; 40932; ""; ""; ""; ""; ""; ""}, 1)
and returns 40909 (1/1/2012) in cell B16.
Step 6 - Replacce errors with blanks
When there are no more values to extract the formula returns errors, the IFERROR function removes the errors and returns blank cells.
IFERROR(SMALL(IF(COUNTIFS(Table1[Start:], "<="&$B$13+ROW($A$1:INDEX($A:$A, $B$14-$B$13))-1, Table1[End:], ">="&$B$13+ROW($A$1:INDEX($A:$A, $B$14-$B$13))-1), "", $B$13+ROW($A$1:INDEX($A:$A, $B$14-$B$13))-1), ROW(A1)), "")
Get excel *.xlsx file
Filter dates outside date ranges.xlsxĀ
2. List dates outside specified date ranges - Excel 365
Excel 365 formula in cell B16:
Explaining formula
FILTER($B$13+SEQUENCE($B$14-$B$13)-1,COUNTIFS(Table1[Start:],"<="&$B$13+SEQUENCE($B$14-$B$13)-1,Table1[End:],">="&$B$13+SEQUENCE($B$14-$B$13)-1)=0)
Step 1 - Calculate days in the date range
The minus sign lets you subtract numbers in an Excel formula.
$B$14-$B$13
becomes
40939-40909 equals 30.
Step 2 - Create a sequence of numbers
The SEQUENCE function creates a list of sequential numbers.
Function syntax: SEQUENCE(rows, [columns], [start], [step])
SEQUENCE($B$14-$B$13)-1
becomes
SEQUENCE(30)-1
becomes
{1; 2; 3; 4; 5; 6; 7; 8; 9; 10; 11; 12; 13; 14; 15; 16; 17; 18; 19; 20; 21; 22; 23; 24; 25; 26; 27; 28; 29; 30} - 1
and returns
{0; 1; 2; 3; 4; 5; 6; 7; 8; 9; 10; 11; 12; 13; 14; 15; 16; 17; 18; 19; 20; 21; 22; 23; 24; 25; 26; 27; 28; 29}
Step 3 - Concatenate strings
The plus sign lets you add numbers in an Excel formula. The ampersand character allows you to concatenate values.
"<="&$B$13+SEQUENCE($B$14-$B$13)-1
becomes
"<="&$B$13+{0; 1; 2; 3; 4; 5; 6; 7; 8; 9; 10; 11; 12; 13; 14; 15; 16; 17; 18; 19; 20; 21; 22; 23; 24; 25; 26; 27; 28; 29}
becomes
"<="&{40909; 40910; 40911; 40912; 40913; 40914; 40915; 40916; 40917; 40918; 40919; 40920; 40921; 40922; 40923; 40924; 40925; 40926; 40927; 40928; 40929; 40930; 40931; 40932; 40933; 40934; 40935; 40936; 40937; 40938}
and returns
{"<=40909"; "<=40910"; "<=40911"; "<=40912"; "<=40913"; "<=40914"; "<=40915"; "<=40916"; "<=40917"; "<=40918"; "<=40919"; "<=40920"; "<=40921"; "<=40922"; "<=40923"; "<=40924"; "<=40925"; "<=40926"; "<=40927"; "<=40928"; "<=40929"; "<=40930"; "<=40931"; "<=40932"; "<=40933"; "<=40934"; "<=40935"; "<=40936"; "<=40937"; "<=40938"}
Step 4 - Count dates outside date ranges
The COUNTIFS function calculates the number of cells across multiple ranges that equals all given conditions.
Function syntax: COUNTIFS(criteria_range1, criteria1, [criteria_range2, criteria2]ā¦)
The less than and the larger than characters are logical operators that you can use in the COUNTIFS function. They allow you to count overlapping date ranges with the specified date range in cells B13 and B14.
COUNTIFS(Table1[Start:],"<="&$B$13+SEQUENCE($B$14-$B$13)-1,Table1[End:],">="&$B$13+SEQUENCE($B$14-$B$13)-1)
returns
{0; 1; 1; 1; 1; 0; 1; 2; 2; 1; 1; 1; 1; 0; 0; 1; 2; 2; 2; 2; 1; 0; 0; 0; 1; 2; 2; 1; 2; 2}.
Step 5 - Check if number is equal to 0 (zero)
The equal sign lets you identify if a number in the array is equal to 0 (zero), the result is a boolean value TRUE or FALSE. 0 (zero) means that the date ranges are not overlapping based on the relative position of the number in the array and the position in the Excel Table. In other words, their positions match which makes it easy to extract the corresponding dates.
COUNTIFS(Table1[Start:],"<="&$B$13+SEQUENCE($B$14-$B$13)-1,Table1[End:],">="&$B$13+SEQUENCE($B$14-$B$13)-1)=0
becomes
{0; 1; 1; 1; 1; 0; 1; 2; 2; 1; 1; 1; 1; 0; 0; 1; 2; 2; 2; 2; 1; 0; 0; 0; 1; 2; 2; 1; 2; 2}=0
and returns
{TRUE; FALSE; FALSE; FALSE; FALSE; TRUE; FALSE; FALSE; FALSE; FALSE; FALSE; FALSE; FALSE; TRUE; TRUE; FALSE; FALSE; FALSE; FALSE; FALSE; FALSE; TRUE; TRUE; TRUE; FALSE; FALSE; FALSE; FALSE; FALSE; FALSE}.
Step 6 - Filter dates based on condition
The FILTER function extracts values/rows based on a condition or criteria.
Function syntax: FILTER(array, include, [if_empty])
FILTER($B$13+SEQUENCE($B$14-$B$13)-1,COUNTIFS(Table1[Start:],"<="&$B$13+SEQUENCE($B$14-$B$13)-1,Table1[End:],">="&$B$13+SEQUENCE($B$14-$B$13)-1)=0)
becomes
FILTER($B$13+SEQUENCE($B$14-$B$13)-1,{TRUE; FALSE; FALSE; FALSE; FALSE; TRUE; FALSE; FALSE; FALSE; FALSE; FALSE; FALSE; FALSE; TRUE; TRUE; FALSE; FALSE; FALSE; FALSE; FALSE; FALSE; TRUE; TRUE; TRUE; FALSE; FALSE; FALSE; FALSE; FALSE; FALSE})
becomes
FILTER({40909; 40910; 40911; 40912; 40913; 40914; 40915; 40916; 40917; 40918; 40919; 40920; 40921; 40922; 40923; 40924; 40925; 40926; 40927; 40928; 40929; 40930; 40931; 40932; 40933; 40934; 40935; 40936; 40937; 40938},{TRUE; FALSE; FALSE; FALSE; FALSE; TRUE; FALSE; FALSE; FALSE; FALSE; FALSE; FALSE; FALSE; TRUE; TRUE; FALSE; FALSE; FALSE; FALSE; FALSE; FALSE; TRUE; TRUE; TRUE; FALSE; FALSE; FALSE; FALSE; FALSE; FALSE})
and returns
{40909; 40914; 40922; 40923; 40930; 40931; 40932}
Step 7 - Shorten the formula
The LET function lets you name intermediate calculation results which can shorten formulas considerably and improve performance.
Function syntax: LET(name1, name_value1, calculation_or_name2, [name_value2, calculation_or_name3...])
FILTER($B$13+SEQUENCE($B$14-$B$13)-1,COUNTIFS(Table1[Start:],"<="&$B$13+SEQUENCE($B$14-$B$13)-1,Table1[End:],">="&$B$13+SEQUENCE($B$14-$B$13)-1)=0)
$B$13 is repeated plenty of times in the formula, I will name it y in this example.
SEQUENCE($B$14-$B$13) is also repeated, I am going to name it x.
LET(y, $B$13, x, SEQUENCE($B$14-y)-1, FILTER(y+x, COUNTIFS(Table1[Start:], "<="&y+x, Table1[End:], ">="&y+x)=0))
3. List empty gaps as date ranges - Excel 365
The following formulas extract empty gaps between given date ranges specified in the Excel Table located in cells A3:B10.
The formulas returns #CALC error if no empty date ranges exist.
The Excel Table lets you easily add or remove date ranges without the need to adjust cell ranges in the formulas.
Excel 365 formula in cell A17:
Excel 365 formula in cell B17:
Explaining the formula in cell A17
The formulas in cells A17 and B17 check between gaps using the end date to the start date, they are displayed if they don't overlap with the original date ranges meaning they must be an empty space.
=FILTER(FILTER(TOCOL(IF((TRANSPOSE(Table4[End:])+1<=Table4[Start:]-1)*(Table4[Start:]-1>=TRANSPOSE(Table4[End:])+1),TRANSPOSE(Table4[End:])+1,"")),TOCOL(IF((TRANSPOSE(Table4[End:])+1<=Table4[Start:]-1)*(Table4[Start:]-1>=TRANSPOSE(Table4[End:])+1),TRANSPOSE(Table4[End:])+1,""))<>""),COUNTIFS(Table4[Start:],"<="&FILTER(TOCOL(IF((TRANSPOSE(Table4[End:])+1<=Table4[Start:]-1)*(Table4[Start:]-1>=TRANSPOSE(Table4[End:])+1),Table4[Start:]-1,"")),TOCOL(IF((TRANSPOSE(Table4[End:])+1<=Table4[Start:]-1)*(Table4[Start:]-1>=TRANSPOSE(Table4[End:])+1),Table4[Start:]-1,""))<>""),Table4[End:],">="&FILTER(TOCOL(IF((TRANSPOSE(Table4[End:])+1<=Table4[Start:]-1)*(Table4[Start:]-1>=TRANSPOSE(Table4[End:])+1),TRANSPOSE(Table4[End:])+1,"")),TOCOL(IF((TRANSPOSE(Table4[End:])+1<=Table4[Start:]-1)*(Table4[Start:]-1>=TRANSPOSE(Table4[End:])+1),TRANSPOSE(Table4[End:])+1,""))<>""))=0)
Step 1 - Specify reference to the Excel Table
Table4[End:]
Step 2 - Transpose dates
The TRANSPOSE function converts a vertical range to a horizontal range, or vice versa.
Function syntax: TRANSPOSE(array)
TRANSPOSE(Table4[End:])
Step 3 - Add 1
TRANSPOSE(Table4[End:])+1
Step 4 - Subtract dates by 1
Table4[Start:]-1
Step 5 - Check if the end dates are equal to or smaller than the start dates
(TRANSPOSE(Table4[End:])+1)<=(Table[Start:]-1)
Step 6 - Multiply arrays (AND logic)
(TRANSPOSE(Table4[End:])+1<=Table4[Start:]-1)*(Table4[Start:]-1>=TRANSPOSE(Table4[End:])+1)
Step 7 - Replace array with end dates
The IF function returns one value if the logical test is TRUE and another value if the logical test is FALSE.
Function syntax: IF(logical_test, [value_if_true], [value_if_false])
IF((TRANSPOSE(Table4[End:])+1<=Table4[Start:]-1)*(Table4[Start:]-1>=TRANSPOSE(Table4[End:])+1),TRANSPOSE(Table4[End:])+1,"")
Step 8 - Rearrange dates to fit a column
The TOCOL function rearranges values in 2D cell ranges to a single column.
Function syntax: TOCOL(array, [ignore], [scan_by_col])
TOCOL(IF((TRANSPOSE(Table4[End:])+1<=Table4[Start:]-1)*(Table4[Start:]-1>=TRANSPOSE(Table4[End:])+1),TRANSPOSE(Table4[End:])+1,""))
Step 9 - Filter out empty values
The FILTER function extracts values/rows based on a condition or criteria.
Function syntax: FILTER(array, include, [if_empty])
FILTER(TOCOL(IF((TRANSPOSE(Table4[End:])+1<=Table4[Start:]-1)*(Table4[Start:]-1>=TRANSPOSE(Table4[End:])+1),TRANSPOSE(Table4[End:])+1,"")),TOCOL(IF((TRANSPOSE(Table4[End:])+1<=Table4[Start:]-1)*(Table4[Start:]-1>=TRANSPOSE(Table4[End:])+1),TRANSPOSE(Table4[End:])+1,""))<>"")
Step 10 - Count dates
The COUNTIFS function calculates the number of cells across multiple ranges that equals all given conditions.
Function syntax: COUNTIFS(criteria_range1, criteria1, [criteria_range2, criteria2]ā¦)
COUNTIFS(Table4[Start:],"<="&FILTER(TOCOL(IF((TRANSPOSE(Table4[End:])+1<=Table4[Start:]-1)*(Table4[Start:]-1>=TRANSPOSE(Table4[End:])+1),Table4[Start:]-1,"")),TOCOL(IF((TRANSPOSE(Table4[End:])+1<=Table4[Start:]-1)*(Table4[Start:]-1>=TRANSPOSE(Table4[End:])+1),Table4[Start:]-1,""))<>""),Table4[End:],">="&FILTER(TOCOL(IF((TRANSPOSE(Table4[End:])+1<=Table4[Start:]-1)*(Table4[Start:]-1>=TRANSPOSE(Table4[End:])+1),TRANSPOSE(Table4[End:])+1,"")),TOCOL(IF((TRANSPOSE(Table4[End:])+1<=Table4[Start:]-1)*(Table4[Start:]-1>=TRANSPOSE(Table4[End:])+1),TRANSPOSE(Table4[End:])+1,""))<>""))
Step 10 - Filter end dates
Filter end dates whose count is equal to 0 (zero) meaning no overlapping.
FILTER(FILTER(TOCOL(IF((TRANSPOSE(Table4[End:])+1<=Table4[Start:]-1)*(Table4[Start:]-1>=TRANSPOSE(Table4[End:])+1),TRANSPOSE(Table4[End:])+1,"")),TOCOL(IF((TRANSPOSE(Table4[End:])+1<=Table4[Start:]-1)*(Table4[Start:]-1>=TRANSPOSE(Table4[End:])+1),TRANSPOSE(Table4[End:])+1,""))<>""),COUNTIFS(Table4[Start:],"<="&FILTER(TOCOL(IF((TRANSPOSE(Table4[End:])+1<=Table4[Start:]-1)*(Table4[Start:]-1>=TRANSPOSE(Table4[End:])+1),Table4[Start:]-1,"")),TOCOL(IF((TRANSPOSE(Table4[End:])+1<=Table4[Start:]-1)*(Table4[Start:]-1>=TRANSPOSE(Table4[End:])+1),Table4[Start:]-1,""))<>""),Table4[End:],">="&FILTER(TOCOL(IF((TRANSPOSE(Table4[End:])+1<=Table4[Start:]-1)*(Table4[Start:]-1>=TRANSPOSE(Table4[End:])+1),TRANSPOSE(Table4[End:])+1,"")),TOCOL(IF((TRANSPOSE(Table4[End:])+1<=Table4[Start:]-1)*(Table4[Start:]-1>=TRANSPOSE(Table4[End:])+1),TRANSPOSE(Table4[End:])+1,""))<>""))=0)
Step 11 - Shorten the formula
The LET function lets you name intermediate calculation results which can shorten formulas considerably and improve performance.
Function syntax: LET(name1, name_value1, calculation_or_name2, [name_value2, calculation_or_name3...])
FILTER(FILTER(TOCOL(IF((TRANSPOSE(Table4[End:])+1<=Table4[Start:]-1)*(Table4[Start:]-1>=TRANSPOSE(Table4[End:])+1),TRANSPOSE(Table4[End:])+1,"")),TOCOL(IF((TRANSPOSE(Table4[End:])+1<=Table4[Start:]-1)*(Table4[Start:]-1>=TRANSPOSE(Table4[End:])+1),TRANSPOSE(Table4[End:])+1,""))<>""),COUNTIFS(Table4[Start:],"<="&FILTER(TOCOL(IF((TRANSPOSE(Table4[End:])+1<=Table4[Start:]-1)*(Table4[Start:]-1>=TRANSPOSE(Table4[End:])+1),Table4[Start:]-1,"")),TOCOL(IF((TRANSPOSE(Table4[End:])+1<=Table4[Start:]-1)*(Table4[Start:]-1>=TRANSPOSE(Table4[End:])+1),Table4[Start:]-1,""))<>""),Table4[End:],">="&FILTER(TOCOL(IF((TRANSPOSE(Table4[End:])+1<=Table4[Start:]-1)*(Table4[Start:]-1>=TRANSPOSE(Table4[End:])+1),TRANSPOSE(Table4[End:])+1,"")),TOCOL(IF((TRANSPOSE(Table4[End:])+1<=Table4[Start:]-1)*(Table4[Start:]-1>=TRANSPOSE(Table4[End:])+1),TRANSPOSE(Table4[End:])+1,""))<>""))=0)
x - TRANSPOSE(Table[End:])+1
y - Table[Start:]-1
z - TOCOL(IF((x<=y)*(y>=x),x,""))
w - TOCOL(IF((x<=y)*(y>=x),y,""))
q - FILTER(z,z<>"")
LET(x,TRANSPOSE(Table[End:])+1,y,Table[Start:]-1,z,TOCOL(IF((x<=y)*(y>=x),x,"")),w,TOCOL(IF((x<=y)*(y>=x),y,"")),q,FILTER(z,z<>""),FILTER(q,COUNTIFS(Table[Start:],"<="&FILTER(w,w<>""),Table[End:],">="&q)=0))
Overlapping category
adam asks: Hi, I have a situation where I want to count if this value is duplicate and if it […]
This article demonstrates formulas that show if a date range is overlapping another date range.Ā The second section shows how […]
I found an old post that I think is interesting to write about today. Think of two overlapping ranges, it […]
Functions in this article
More than 1300 Excel formulas
Excel categories
4 Responses to “List dates outside specified date ranges”
Leave a Reply
How to comment
How to add a formula to your comment
<code>Insert your formula here.</code>
Convert less than and larger than signs
Use html character entities instead of less than and larger than signs.
< becomes < and > becomes >
How to add VBA code to your comment
[vb 1="vbnet" language=","]
Put your VBA code here.
[/vb]
How to add a picture to your comment:
Upload picture to postimage.org or imgur
Paste image link to your comment.
typo??
INDEX($A:$A, $B$14-$B$13) --> INDEX($A:$A, $B$14-$B$13+1)
aMareis,
I don“t think so. Can you explain why?
If B9=2012-01-30 and B10=2012-01-30 then ????
Your result omit 2012-01-31.
i don't know but it does not work for me for 180 lines of range dates can you please help me ?