Need to find is value is between multiple ranges

Ronnie12345

New Member
Joined
Mar 24, 2017
Messages
18
Hi excel wizards,

I need to find if dates are in holiday date ranges

For example is 03/01/2020 within the date ranges below.
I could do this with a nested IF statement but I'm determined to evolve beyond that!
Can you suggest a formula to do this, please?

01/01/2020 05/01/2020
15/02/2020 23/02/2020
04/04/2020 19/04/2020
23/05/2020 31/05/2020
21/07/2020 30/08/2020
24/10/2020 01/11/2020
19/12/2020 31/12/2020
 

Excel Facts

Square and cube roots
The =SQRT(25) is a square root. For a cube root, use =125^(1/3). For a fourth root, use =625^(1/4).
Do you need to test each individual pair of dates to see if the date falls between them or just if the date falls between any of those pairs of dates, ie produce 7 results or just the 1 result?
 
Upvote 0
Hi,

Take a look at this. The result of the formula will return the number of the range in which the date falls in between. 0 as a result will mean no range applies.


Book1
ABCDE
13-1-20201
21-1-20205-1-2020
315-2-202023-2-2020
44-4-202019-4-2020
523-5-202031-5-2020
621-7-202030-8-2020
724-10-20201-11-2020
819-12-202031-12-2020
Sheet1
Cell Formulas
RangeFormula
E1=SUMPRODUCT(($D1>=$A$2:$A$8)*($D1<=$B$2:$B$8)*(ROW($A$2:$A$8)-1))
 
Upvote 0
Since your holidays are listed chronologically throughout the year in columns A:B, you should be able to just use this.
If January 1 was not in a holiday period you would need a slight adjustment but I'm guessing that in your location January 1 will always be a holiday. (y)


Excel 365 (Windows) 32 bit
ABCDE
1StartEndDateIn Holiday?
21/01/20205/01/20203/01/2020TRUE
315/02/202023/02/202021/01/2020FALSE
44/04/202019/04/20201/11/2020TRUE
523/05/202031/05/2020
621/07/202030/08/2020
724/10/20201/11/2020
819/12/202031/12/2020
Check Holidays
Cell Formulas
RangeFormula
E2=VLOOKUP(D2,A$2:B$8,2)>=D2
 
Upvote 0
Hi,

Take a look at this. The result of the formula will return the number of the range in which the date falls in between. 0 as a result will mean no range applies.

ABCDE
13-1-20201
21-1-20205-1-2020
315-2-202023-2-2020
44-4-202019-4-2020
523-5-202031-5-2020
621-7-202030-8-2020
724-10-20201-11-2020
819-12-202031-12-2020

<colgroup><col style="width: 25pxpx"><col><col><col><col><col></colgroup><thead>
</thead><tbody>
</tbody>
Sheet1

Worksheet Formulas
CellFormula
E1=SUMPRODUCT(($D1>=$A$2:$A$8)*($D1<=$B$2:$B$8)*(ROW($A$2:$A$8)-1))

<thead>
</thead><tbody>
</tbody>

<tbody>
</tbody>


Brilliant, that works perfectly.Thank you.
What if I wanted to return a value in a third column, e.g. 03/01/2020 would return Christmas Holiday...

01/01/2020 05/01/2020 Christmas Holiday
15/02/2020 23/02/2020 February Half-Term
04/04/2020 19/04/2020 Easter Holiday
23/05/2020 31/05/2020 Spring Half-Term
21/07/2020 30/08/2020 Summer Holiday
24/10/2020 01/11/2020 November Half-term
19/12/2020 31/12/2020 Christmas Holiday
 
Upvote 0
Since your holidays are listed chronologically throughout the year in columns A:B, you should be able to just use this.
If January 1 was not in a holiday period you would need a slight adjustment but I'm guessing that in your location January 1 will always be a holiday. (y)

Excel 365 (Windows) 32 bit
ABCDE
1StartEndDateIn Holiday?
21/01/20205/01/20203/01/2020TRUE
315/02/202023/02/202021/01/2020FALSE
44/04/202019/04/20201/11/2020TRUE
523/05/202031/05/2020
621/07/202030/08/2020
724/10/20201/11/2020
819/12/202031/12/2020

<colgroup><col style="width: 25pxpx"><col><col><col><col><col></colgroup><thead>
</thead><tbody>
</tbody>
Check Holidays

Worksheet Formulas
CellFormula
E2=VLOOKUP([COLOR=rgb(255]D2,A$2:B$8,2[/COLOR])>=D2

<thead>
</thead><tbody>
</tbody>

<tbody>
</tbody>


Nice one, didn't think of this!
 
Upvote 0
With @Peter_SSs suggestion (make sure you check his assumption of chronologically sorted dates) just change the range in the VLOOKUP.
Following my suggestion:


Book1
ABCDEF
13-1-20201Christmas Holiday
21-1-20205-1-2020Christmas Holiday
315-2-202023-2-2020February Half-Term
44-4-202019-4-2020Easter Holiday
523-5-202031-5-2020Spring Half-Term
621-7-202030-8-2020Summer Holiday
724-10-20201-11-2020November Half-term
819-12-202031-12-2020Christmas Holiday
Sheet1
Cell Formulas
RangeFormula
E1=SUMPRODUCT(($D1>=$A$2:$A$8)*($D1<=$B$2:$B$8)*(ROW($A$2:$A$8)-1))
F1=INDEX(C2:C8,SUMPRODUCT(($D1>=$A$2:$A$8)*($D1<=$B$2:$B$8)*(ROW($A$2:$A$8)-1)))
 
Last edited:
Upvote 0
With Peter_SSs suggestion (make sure you check his assumption of chronologically sorted dates)
I did qualify that in my post. ;)


With @jorismoerings latest suggestion note ..

- if you have a column (or row) of dates to check add the absolute reference $ signs on the C2:C8 range in the F1 formula before copying down/across.

- if the date being checked is not in any holiday, the formulas will return "Christmas Holiday"



For my suggestion (same assumption as before), if you want to know which holiday it would be

Excel Workbook
ABCDE
1StartEndDateIn Holiday?
21/01/20205/01/2020Christmas Holiday3/01/2020Christmas Holiday
315/02/202023/02/2020February Half-Term21/01/2020No holiday
44/04/202019/04/2020Easter Holiday1/11/2020November Half-term
523/05/202031/05/2020Spring Half-Term
621/07/202030/08/2020Summer Holiday
724/10/20201/11/2020November Half-term
819/12/202031/12/2020Christmas Holiday
Check Holidays
 
Last edited:
Upvote 0

Forum statistics

Threads
1,213,546
Messages
6,114,256
Members
448,558
Latest member
aivin

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top