Date values problem

mattbird

Active Member
Joined
Oct 15, 2013
Messages
305
Office Version
  1. 2016
Hi,

I’m using excel 2016 and trying to use a formula to put specific text into a cell.

1st problem:

If I enter a date between 1 Apr and end of Jun in B3, I want A3 to show Q1
1 Jul to end of Sep - Q2
1 Oct to end of Dec - Q3
1 Jan to end of Mar - Q4

I’ve been trying the following formula in cell A3:
=IF(AND(B3>=DATEVALUE(“01/04/2023”),B3<=DATEVALUE(“30/06/2023”)),”Q1”, IF(AND(B3>=DATEVALUE(“01/07/2023”),B3<=DATEVALUE(“30/09/2023”)),”Q2”, and so on. This does work, however ever year I would need to amend the date.
Can I get the formula to do this?

2nd problem

If I then put a new date in cell C3 I want it to do the same overriding Cell B3 input. If I then put a further new date in cell D3 again I want it to do the same, overriding both cell B3 and C3.

Can this be done?
 

Excel Facts

Which lookup functions find a value equal or greater than the lookup value?
MATCH uses -1 to find larger value (lookup table must be sorted ZA). XLOOKUP uses 1 to find values greater and does not need to be sorted.
If I enter a date between 1 Apr and end of Jun in B3, I want A3 to show Q1
1 Jul to end of Sep - Q2
1 Oct to end of Dec - Q3
1 Jan to end of Mar - Q4

I’ve been trying the following formula in cell A3:
=IF(AND(B3>=DATEVALUE(“01/04/2023”),B3<=DATEVALUE(“30/06/2023”)),”Q1”, IF(AND(B3>=DATEVALUE(“01/07/2023”),B3<=DATEVALUE(“30/09/2023”)),”Q2”, and so on. This does work, however ever year I would need to amend the date.
Can I get the formula to do this?
Try this formula:
Excel Formula:
=LOOKUP(MONTH(B3),{1,4,7,10},{4,1,2,3})
 
Upvote 0
I’m using excel 2016

I suggest that you update your Account details (or click your user name at the top right of the forum) so helpers always know what Excel version(s) & platform(s) you are using as the best solution often varies by version. (Don’t forget to scroll down & ‘Save’)

For the 1st part, how about
Excel Formula:
=CHOOSE(INT((MONTH(B3)-1)/3)+1,"Q4","Q1","Q2","Q3")
 
Upvote 0
2nd problem

If I then put a new date in cell C3 I want it to do the same overriding Cell B3 input. If I then put a further new date in cell D3 again I want it to do the same, overriding both cell B3 and C3.
As long as there are no blanks in the middle of your data on row 3, try this version for that:
Excel Formula:
=LOOKUP(MONTH(INDEX(B3:ZZ3,1,COUNTA(B3:ZZ3))),{1,4,7,10},{"Q4","Q1","Q2","Q3"})

I also missed that you wanted "Q" in front of all the numbers in my first reply.
So it would just need to be amended to:
Excel Formula:
=LOOKUP(MONTH(B3),{1,4,7,10},{"Q4","Q1","Q2","Q3"})
 
Upvote 0
Solution
As long as there are no blanks in the middle of your data on row 3, try this version for that:
Excel Formula:
=LOOKUP(MONTH(INDEX(B3:ZZ3,1,COUNTA(B3:ZZ3))),{1,4,7,10},{"Q4","Q1","Q2","Q3"})

I also missed that you wanted "Q" in front of all the numbers in my first reply.
So it would just need to be amended to:
Excel Formula:
=LOOKUP(MONTH(B3),{1,4,7,10},{"Q4","Q1","Q2","Q3"})
The top code was perfect, does what I needed and also works with Date/time format. Thanks
 
Upvote 0
You are welcome.
Glad we were able to help!
 
Upvote 0

Forum statistics

Threads
1,213,506
Messages
6,114,024
Members
448,543
Latest member
MartinLarkin

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