Add IRR & NPV to Pivot Table as Calculated Field

JonesyUK

Board Regular
Joined
Oct 11, 2005
Messages
190
Office Version
  1. 365
Platform
  1. Windows
Dear Experts,

Can you please tell me how to add IRR and NPV to a Pivot Table as a Calculated Field.

I am using Excel 2010

Many thanks,
JonesyUK
 

Excel Facts

Which lookup functions find a value equal or greater than the lookup value?
MATCH uses -1 to find larger value (lookup table must be sorted ZA). XLOOKUP uses 1 to find values greater and does not need to be sorted.
These functions are not available in PowerPivot, so you cannot use them directly. But you could calculate them. Can you tell us more about your model? (Your tables and their relationships.)
 
Upvote 0
Hi Laurent,

I am familiar with the calculations, however, my pivot table has a number of filters, and everytime I filter the table, I am left with the #NUM! errors for blank rows below the totals... I also have applied formatting to the Pivot Table using Slicer Tools, and I can't maintain the formatting with formulas for IRR and NPV.

As you mention above, I cannot use the calculations directly, so perhaps this is not possible, which is a great pity, because it would add a lot of value.

Not sure what additional info you were looking for about the model:
Column 1 = Country
Column 2 = Investment
Columns 3 to 14 has the Return Amounts.

Column 15 has IRR
Column 16 has NPV

Thanks for your assistance.
 
Upvote 0
OK. Am I right, if I assume that you are not using PowerPivot, but a regular pivot table with formulas next to the table?
 
Upvote 0
I think that I've got this to work as closely as possible. I've used Conditional Formatting to hide Errors. It's not perfect, and I lose some formatting, but it will have to do. Thanks for your help.
 
Upvote 0
These functions are not available in PowerPivot, so you cannot use them directly. But you could calculate them. Can you tell us more about your model? (Your tables and their relationships.)

Hi Laurent,

Unlike JonesyUK, I am trying to calculate NPV in PowerPivot. Since you've recently expressed an interest in this topic, maybe you can help.

My table has years in one column, cashflows in another column and I want to calculate a column to show what the NPV of future cashflows would be as at each year (not just for the current year). I can do this in Excel using the NPV function. In PowerPivot, I can do it for one year by inserting a calculated column which discounts the cashflow column to its present values as at that year, and then sum the discounted cashflows, but I have 50 years, and don't really want to insert that many columns. Is there a way of duplicating the functionality of Excel's NPV function so that I can return the values all in one column?

Any help would be much appreciated.

Mike.
 
Upvote 0
In case anyone is interested, I've figured out a couple of ways of doing this. If I have a table that looks like this, where Y is a year, c is a series of cashflows, r is a discount rate for the year, p is a project number, I can calculate N, the NPV of future cashflows in a calculated column with the formulas:


=SUMX(Table1,if(Table1[Y]>=EARLIER(Table1[Y])&&Table1[p]=earlier(Table1[p]),Table1[C]/(1+earlier(table1[r]))^(Table1[Y]-EARLIER(Table1[Y]))))


or


=sumx(filter(Table1,Table1[Y]>=earlier(Table1[Y])&&Table1[p]=earlier(Table1[p])),Table1[C]/(1+earlier(table1[r]))^(Table1[Y]-EARLIER(Table1[Y])))




Y C r p N
2005 10 0.065 1 33
2006 7 0.09 1 24
2007 14 0.04 1 19
2008 5 0.02 1 5
2005 98 0.065 2 473
2006 76 0.09 2 386
2007 54 0.04 2 351
2008 309 0.02 2 309


I would still be interested if anyone can think of a better (more elegant or efficient) way of doing this. I'm building a complex model and performance will be an issue.


Cheers,


Mike.
 
Upvote 0
Since calculated columns are persisted, performance should not be an issue, as long as you have enough memory. Calculated columns only impact the time it takes to refresh (process) your data model.

Using CALCULATE and time intelligence functions might help making your model more maintainable, provided you have a date table, since you would not have to referrence p or any other column in your table (except Y and C).
 
Upvote 0

Forum statistics

Threads
1,213,506
Messages
6,114,024
Members
448,543
Latest member
MartinLarkin

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