Calc Prorated Cost based on Specific Days in a Given Month & Year Range

R

retailmessiah

Hello Everyone,

I beg your assistance.

I posted this last year, and reread this recently. I've come to
realize how crappily I described this, and thought I'd give it another
go. I have the need to take 2 dates, possibly in different years, and
calculate Cost totals between them. The tricky part is that the price
is annual, but we prorate it to only the days used. We also need to do
the calculation on a daily level as the price for service is Monthly,
regardless of how many days are in a month. We do however calculate it
down to the day. Confused yet? Let me give an example.


This is all based on the annual cost, which will change. I may
implement it using monthly cost, but all the numbers play off of each
other.

Annual Cost: $1200.00 (which is Monthly Price = $1200.00/12 Months =
$100)
Days Service was used: 11/02/2004 - 03/16/06
Price per Day: [28 Day Month]= $3.57/day, [29 Day Month]=$3.45/day,
[30 Day Month]=$3.33/day, [31 Day Month]=$3.23/day

Ok, so they only have to pay for the days that they used.

Now, to calculate the daily price, I need to know how many days are in
November of '04, and March of '06. All the rest we can use static
monthly pricing. So, let's get back to basics:

Thirty days hath September, April, June, and November; All the rest
have thirty-one Excepting February alone: Which hath but twenty-eight,
in fine, Till Leap Year gives it twenty-nine.

November '04 = 30 days. So the price per Day for November is $3.33/
day. Taking into account that the service started on November 2nd,
that would mean 29 days of service were used. Final November calc
would be 29 * $3.33 = $96.57

March 06 = 31 days. So the price per Day for March is $3.23/day.
Taking into account that the service ended on March 16th, that would
mean 16 days of service were used. Final March calc would be 16 *
$3.23 = $51.68

December '04, the 12 months of 2005, and January '06, and February '06
= 15 Months, which is $1500.

Total Daily prorated bill for this customer would be: $1648.25.

All the times I've attempted this, it seems to work sometimes, but
usually not in the same month. Other things that I'm concerned about
is creating a formula that will evaluate how many days are in the
specific month and
year. I'm pretty good with subtracting dates, but I don't know how to
tell excel to do that with the first and last. I'm struggling with how
to separate full months from partial ones. I also need this to account
for leap years. The leap year, .. well, the days in the month only
matter if the starting date or ending date fall in the middle of the
month.

I hope this better explains the issue, so that by asking the right
question, I can hope to receive the right answer. :) I would
appreciate any guidance, or help that anyone can provide me.

Please and Thank You :),
-John
 
J

joeu2004

Annual Cost: $1200.00 (which is Monthly Price = $1200.00/12 Months = $100)
Days Service was used: 11/02/2004 - 03/16/06
Price per Day: [28 Day Month]= $3.57/day, [29 Day Month]=$3.45/day,
[30 Day Month]=$3.33/day, [31 Day Month]=$3.23/day
[....]
Total Daily prorated bill for this customer would be: $1648.25

Per your specification (rounding the per diem rate):

=IF(EOMONTH(A1,0)=EOMONTH(A2,0),
IF(AND(DAY(A1)=1, A2=EOMONTH(A2,0)),
100, (A2-A1+1)*ROUND(100/DAY(EOMONTH(A1,0)),2)),
100*(12*(YEAR(A2)-YEAR(A1)) + MONTH(A2)-MONTH(A1)-1) +
IF(DAY(A1)=1, 100, (EOMONTH(A1,0)-A1+1)*ROUND(100/DAY(EOMONTH(A1,0)),
2)) + IF(A2=B2, 100, DAY(A2)*ROUND(100/DAY(EOMONTH(A2,0)),2)))

The formula could be simplified somewhat if you did not round the per
diem rate, but instead rounded the days times per diem rate. Because
you round the per diem rate,
daysPerMonth * perDiemRate is not $100. So we must special-case
certain boundary conditions.

Note the EOMONTH() is part of the Analysis ToolPak add-in. See Help
for EOMONTH if you get a #NAME! error.

The theory of operation is (where A1 is the start date, and A2 is the
end date):

1. The per diem rate is 100 / daysPerMonth, rounded to a penny, where
daysPerMonth is DAY(EOMONTH(date,0)).

2. If A1 and A2 are in the same month:

a. If A1 is the 1st of the month and A2 is the end of the month,
then $100.

b. Otherwise, the per diem rate times the number of days between
A1 and A2 inclusive.

3. Otherwise add:

a. 100 times the number of months between A1 and A2. I do not use
DATEDIF(A1,A2,"m")-1 because of the way that DATEDIF() computes
elapsed months with respect to differ days of the starting and ending
months.

b. If A1 is the 1st of the month, then $100; otherwise, the per
diem rate times the number days between A1 and the end of month
inclusive.

c. If A2 is the end of the month, then $100; otherwise, the per
diem rate times the number of days between the 1st of the month and A2
inclusive.

Caveat: Although I have made every effort to desk-check the logic, I
only tested a few cases. It would behoove you to test all conditions,
including situations where the day of the starting month is less than,
equal to, and greater than the day of the ending month in each of the
applicable conditions described above.

If you encounter an error of mine that you cannot fix, let me know.

----- Original Posting -----

Hello Everyone,

I beg your assistance.

I posted this last year, and reread this recently. I've come to
realize how crappily I described this, and thought I'd give it another
go. I have the need to take 2 dates, possibly in different years, and
calculate Cost totals between them. The tricky part is that the price
is annual, but we prorate it to only the days used. We also need to do
the calculation on a daily level as the price for service is Monthly,
regardless of how many days are in a month. We do however calculate it
down to the day. Confused yet? Let me give an example.

This is all based on the annual cost, which will change. I may
implement it using monthly cost, but all the numbers play off of each
other.

Annual Cost: $1200.00 (which is Monthly Price = $1200.00/12 Months =
$100)
Days Service was used: 11/02/2004 - 03/16/06
Price per Day: [28 Day Month]= $3.57/day, [29 Day Month]=$3.45/day,
[30 Day Month]=$3.33/day, [31 Day Month]=$3.23/day

Ok, so they only have to pay for the days that they used.

Now, to calculate the daily price, I need to know how many days are in
November of '04, and March of '06. All the rest we can use static
monthly pricing. So, let's get back to basics:

Thirty days hath September, April, June, and November; All the rest
have thirty-one Excepting February alone: Which hath but twenty-eight,
in fine, Till Leap Year gives it twenty-nine.

November '04 = 30 days. So the price per Day for November is $3.33/
day. Taking into account that the service started on November 2nd,
that would mean 29 days of service were used. Final November calc
would be 29 * $3.33 = $96.57

March 06 = 31 days. So the price per Day for March is $3.23/day.
Taking into account that the service ended on March 16th, that would
mean 16 days of service were used. Final March calc would be 16 *
$3.23 = $51.68

December '04, the 12 months of 2005, and January '06, and February '06
= 15 Months, which is $1500.

Total Daily prorated bill for this customer would be: $1648.25.

All the times I've attempted this, it seems to work sometimes, but
usually not in the same month. Other things that I'm concerned about
is creating a formula that will evaluate how many days are in the
specific month and
year. I'm pretty good with subtracting dates, but I don't know how to
tell excel to do that with the first and last. I'm struggling with how
to separate full months from partial ones. I also need this to account
for leap years. The leap year, .. well, the days in the month only
matter if the starting date or ending date fall in the middle of the
month.

I hope this better explains the issue, so that by asking the right
question, I can hope to receive the right answer. :) I would
appreciate any guidance, or help that anyone can provide me.

Please and Thank You :),
-John
 
J

joeu2004

Errata....

[....]
IF(A2=B2, 100, DAY(A2)*ROUND(100/DAY(EOMONTH(A2,0)),2)))

I see one typo (B2), left over from debugging. The correct intended
formula is:

=IF(EOMONTH(A1,0)=EOMONTH(A2,0),
IF(AND(DAY(A1)=1, A2=EOMONTH(A2,0)),
100, (A2-A1+1)*ROUND(100/DAY(EOMONTH(A1,0)),2)),
100*(12*(YEAR(A2)-YEAR(A1)) + MONTH(A2)-MONTH(A1)-1) +
IF(DAY(A1)=1, 100, (EOMONTH(A1,0)-A1+1)*ROUND(100/DAY(EOMONTH(A1,0)),
2)) + IF(A2=EOMONTH(A2,0), 100, DAY(A2)*ROUND(100/DAY(EOMONTH(A2,0)),
2)))
 
J

joeu2004

Clarification....

3. Otherwise add:

a. 100 times the number of months between A1 and A2.

That is: the number of months __in_between__ A1 and A2, not including
A1 or A2. For example, if A1 is 1/1/2004 and A2 is 3/1/2004, the
number of months in between them is one, namely Feb, for the purpose
of this part of the computation.
 

Ask a Question

Want to reply to this thread or ask your own question?

You'll need to choose a username for the site, which only take a couple of moments. After that, you can post your question and our members will help you out.

Ask a Question

Top