distribute recurring expenses over years by matching dates to enter amounts in cells for daily totals

rkobeyer

New Member
Joined
Jul 14, 2011
Messages
44
I have a very large spreadsheet that will show daily expenses for over 2 years.

I want to be able to quickly enter regularly recurring expenses and see daily totals. I then plan to add income later and calculate daily cash-flow.

I though I had found a suitable formula and everything seemed to be working fine but then Excel error message says "This formula can't be entered because it uses more than 64 levels of nesting."

This sheet matches the dates in the payments columns from columns F to HE with the dates in daily expenses from Columns HH to ASV.

If the dates match, the amounts in columns F to HE get entered into the correct cells in Columns HH to ASV.

I am not allowed to attach my Excel spreadsheet for some reason but I have included a screen-shot below.

Is there a different formula that I can use that will do the exact same thing?

Or is there a better way to enter recurring expenses into a spreadsheet and then be able to see this daily?

This will be the foundation for an extremely detailed daily cash-flow spreadsheet.I will then display the daily totals on an easy to read yearly calendar.

To fit everything into the screen-shot I have had to hide a lot of the columns, but hopefully you will see what I am trying to do.

fvfvht.jpg

cNxZBgj
 

Excel Facts

Back into an answer in Excel
Use Data, What-If Analysis, Goal Seek to find the correct input cell value to reach a desired result
I haven't actually tested this, since it would take a while for me to recreate your test sheet, but try this:

=SUMPRODUCT(--($F7:$ED7=HN$4),$G7:$EE7)

Consider using the HTML Maker in my signature to post a computer readable sample sheet.
 
Upvote 0
=SUMPRODUCT(--($F7:$ED7=HN$4),$G7:$EE7)

Wow! I was speechless when I copied that in and it worked perfectly!
Thanks so much!

Now I just need to figure out a simpler way to do the payments. Rather than allocating each payment to a date manually in columns F to HE it would be nice to just put in the start date and end date only, and allocate the payments to be every few days or weeks, months etc. and then those amounts are automatically entered into the correct cells in Columns HH to ASV.

But I guess that's a problem for another thread.
 
Upvote 0
Wow! I was speechless when I copied that in and it worked perfectly!
Thanks so much!

Now I just need to figure out a simpler way to do the payments. Rather than allocating each payment to a date manually in columns F to HE it would be nice to just put in the start date and end date only, and allocate the payments to be every few days or weeks, months etc. and then those amounts are automatically entered into the correct cells in Columns HH to ASV.

But I guess that's a problem for another thread.


I built a similar till last year att work and the problem with a formula approach, especially that Long is that they are not transparent. It becomes almost impossible to audit them and then you dont really trust the output.

I built a macro that just takes the expense and goes out through a timeline table and writes the value. Very fast and easy to update and check. Then you can define the timing as you wish, every monday, every 7 days, once a quarter etc. The big benefit is then that you can get the liquidity per day (pro tip for liquidity planing is to graph the planed values vs acctuals, then you very easily see the fit and can then be more confident in the planing around it)
 
Upvote 0

Forum statistics

Threads
1,214,575
Messages
6,120,344
Members
448,956
Latest member
Adamsxl

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