Escalation Calculation

Hydestone

Board Regular
Joined
Mar 29, 2010
Messages
109
I have a spreadsheet which contains pricing information which I refer to when creating estimates. When I enter the pricing information, I record the year I entered the amount. I'd like the spreadsheet to show both the escalated rate and also the escalated rate. Unfortunately, escalation does not occur at the same rate each year. I track the escalation percentages by year on a separate tab.

Any suggestions on a formula that would update the unit cost automatically?

The data is stored as follows:

Sheet Name = Unit Prices
Original price stored in column D.
Year original price entered in column E.
Escalated price stored in column F.
D E F
$5,000 2016 $5,408

formula would be $5,000 X 1.03 X 1.05 X 1.06 = $5,408

Sheet Name - Escalation Amounts
Year stored in column A
Escalation amount in column B

Ie:
2015 0%
2016 3%
2017 3%
2018 5%
2019 6%

I don't need to keep this on a separate sheet...can move to same sheet as cost information if easier.

Any suggestions?

Thanks
 

Some videos you may like

Excel Facts

What is the shortcut key for Format Selection?
Ctrl+1 (the number one) will open the Format dialog for whatever is selected.

Crystalyzer

Board Regular
Joined
Oct 18, 2011
Messages
177
1st, your math is wrong. 5,000 x 1.03 x 1.05 x 1.06 = 5,731.95 not 5,408.

The solution is a formula using the FVSCHEDULE, INDIRECT, and MATCH functions.

Assumption: Years and Escalation Percentages start in cell A1 on the Escalation Amounts tab

Steps
  1. Create a dynamic range name called YEARS in the Escalation Amounts tab that will contain the years.
    1. Formula for this range name is
      Code:
      =OFFSET('Escalation Amounts'!$A$1,0,0,COUNTA('Escalation Amounts'!$A:$A))
    2. This will allow you to use this going forward without having to change any formulas when you enter the escalation percentage for 2020 and beyond.
  2. Insert this formula in Cell F1 and copy down the column
    1. Code:
      =FVSCHEDULE(D1,INDIRECT("'Escalation Amounts'!B" & MATCH(E1,Years)+1 & ":B" & COUNTA('Escalation Amounts'!B:B)))
 

Forum statistics

Threads
1,089,420
Messages
5,408,122
Members
403,185
Latest member
sp646

This Week's Hot Topics

  • help please
    SORRY NOT ANY GOOD AT EXCEL SO HELP WOULD BE MUCH APPRECIATED this formula is in a sheet called ignore...
  • two formulas needed
    Hello, I'll try my best to explain this: First formula needed in Sheet1 cell A2: If Sheet1 cell B2 = Sheet2 cell B2 then return a 1. If not then...
  • Dynamic Counts
    Good afternoon, we are tidying up some data & the data seems to be growing quicker than we are tidying it up! What we confirm (by reviewing it...
  • Help Excel formula eliminate duplicate values and keep only 2 identical rows.
    as picture below column A has a duplicate value. but the values are not the same as the rule. sometimes 4 rows, sometimes 10 rows or 7 or 9...
  • Macro Compile Error Sub or Function not defined
    Hello, I am trying to run macros from a validation list, all macros have been created and run perfectly on there own but I'm getting a compile...
  • Last row combined with Current Region VBA
    I'm generally happy finding the last row of data through something like Lastrow = Cells(Rows.Count, "D").End(xlUp) but I don't always receive data...
Top