Lookup problem

arlene_fool

Board Regular
Joined
Feb 17, 2007
Messages
55
I am working on a spreadsheet to track my companys accounts receivables, i want to it to age based on todays date, whereas before i just aged it all to the end of the month. i have created this formula

=LOOKUP(($D$5-F26),{1,30,61,91,0},{"Current","30-60","61-90","90+",""})

where D5 is =today() and F26 is the invoice date.

most of it works, except any invoices over 92days are blank, when they should say "90+"
 

Excel Facts

VLOOKUP to Left?
Use =VLOOKUP(A2,CHOOSE({1,2},$Z$1:$Z$99,$Y$1:$Y$99),2,False) to lookup Y values to left of Z values.
i need the blank space though. we leave blank spaces between different customers. and i dont want it to tell me its "current" etc.
 
Upvote 0
i need the blank space though. we leave blank spaces between different customers. and i dont want it to tell me its "current" etc.

I don't understand your requirements....My formula will provide you the correct ageing description based on the invoice date being in F27 and the current date in D5. Can you clarify what you're looking for?
 
Upvote 0
actually i figured it out by mistake. if the date cell is left blank and you subtract it from todays date, it doesnt equal 0, it makes some big number, so when i changed that 0 to 1000, and it works now.

but thank you, now i just need to get the conditional formatting to work.
 
Upvote 0
Just add this to Barrie's Formula
Code:
=IF(F26,LOOKUP(($D$5-F26),{0,30,61,91},{"Current","30-60","61-90","90+"}),"")
Also, why do you need $D$5? You could use
Code:
=IF(F26,LOOKUP((TODAY()-F26),{0,30,61,91},{"Current","30-60","61-90","90+"}),"")
lenze
 
Upvote 0

Forum statistics

Threads
1,214,626
Messages
6,120,602
Members
448,974
Latest member
ChristineC

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