IF statement with date calculation within - SOLVED

insomnia79

Board Regular
Joined
Apr 12, 2006
Messages
62
Hi all,

I have several columns as so:

B - Patient Surname
C - First Surname
D - Postcode
E - Date
F - Results of If Statement (Days Difference)

I am looking to comapre b, c, d with teh previous cells to make sure I am looking at the same person hcen the AND statement. If they all match then if subtracts the latest date (column E) from an ealier date for the same person. If the person is different it will return a 0. If the date is the same ti will return a 0.

I have done this so far - =IF(AND(B2=B1,C2=C1, D2=D1),(E2-E1),0)

What I am struggling to do is if the number of days (E2-E1) is 0-3 then for the result to show the text "Less then 3". If the value is 4 - 7 then to have it read "Less then 7", anything over 7 to read "OVer 7".

Can anyone help?
 

Excel Facts

Test for Multiple Conditions in IF?
Use AND(test, test, test, test) or OR(test, test, test, ...) as the logical_test argument of IF.

Gerald Higgins

Well-known Member
Joined
Mar 26, 2007
Messages
9,258
Do you want this text to be returned in the same cell as your existing formula ?

If so,
Code:
=IF(AND(B2=B1,C2=C1,D2=D1),IF((E2-E1)<=3,"Less than or equal 3",IF((E2-E1)<=7,"Less than or equal to 7","Over 7")))
 

insomnia79

Board Regular
Joined
Apr 12, 2006
Messages
62
Hi Gerald,

Thanks for the quick reply. It does work and I see where I went wrong with confusion on the IF statement within for the date.

One minor problem is that when the person changes (so when b,c,d dont match up with the previous row) the result returned is FALSE.

Can I change the formula so it is blank instead?

Many thanks
 

Gerald Higgins

Well-known Member
Joined
Mar 26, 2007
Messages
9,258
Sorry, I should have fixed that myself.

Here you go.

Code:
=IF(AND(B2=B1,C2=C1,D2=D1),IF((E2-E1)<=3,"Less than or equal 3",IF((E2-E1)<=7,"Less than or equal to 7","Over 7")),"")
 

Peter_SSs

MrExcel MVP, Moderator
Joined
May 28, 2005
Messages
57,411
Office Version
  1. 365
Platform
  1. Windows
insomnia79

You might like to try this one as well:
Code:
=IF(B1&C1&D1=B2&C2&D2,LOOKUP(E2-E1,{0,4,8},{"less than or equal to 3","less than or equal to 7","Over 7"}),"")
 

insomnia79

Board Regular
Joined
Apr 12, 2006
Messages
62
I wish I had asked here sooner!

Thanks for the replies, both of them work very well indeed. The Lookup statement while looking simple does confuse me. I will pick it apart when I have the time.

Thanks for your help.
 

insomnia79

Board Regular
Joined
Apr 12, 2006
Messages
62
How could I make the formula look for the same date and return a value of 'Same Day"?

I think it would be another Nested part but can't see where I would put it.
 

insomnia79

Board Regular
Joined
Apr 12, 2006
Messages
62
Its alright I sorted it.... :)

=IF(AND(B2=B1,C2=C1,D2=D1),IF(E2=E1,"Same Day",IF((E2-E1)<=3,"
<3 Days",IF((E2-E1)<=7,"<7 Days",">7 Days"))),"")
 

Peter_SSs

MrExcel MVP, Moderator
Joined
May 28, 2005
Messages
57,411
Office Version
  1. 365
Platform
  1. Windows
.. or again using the LOOKUP
Code:
=IF(B1&C1&D1=B2&C2&D2,LOOKUP(E2-E1,{0,1,4,8},{"same day","less than 3","less than 7","Over 7"}),"")
 

Forum statistics

Threads
1,181,657
Messages
5,931,265
Members
436,785
Latest member
KingGideon

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
Top