Page 1 of 2 12 LastLast
Results 1 to 10 of 13

Add IRR & NPV to Pivot Table as Calculated Field

This is a discussion on Add IRR & NPV to Pivot Table as Calculated Field within the Power BI forums, part of the Question Forums category; Dear Experts, Can you please tell me how to add IRR and NPV to a Pivot Table as a Calculated ...

  1. #1
    Board Regular
    Join Date
    Oct 2005
    Posts
    161

    Default Add IRR & NPV to Pivot Table as Calculated Field

    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

  2. #2
    Board Regular
    Join Date
    Apr 2012
    Posts
    223

    Default Re: Add IRR & NPV to Pivot Table as Calculated Field

    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.)

  3. #3
    Board Regular
    Join Date
    Oct 2005
    Posts
    161

    Default Re: Add IRR & NPV to Pivot Table as Calculated Field

    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.

  4. #4
    Board Regular
    Join Date
    Apr 2012
    Posts
    223

    Default Re: Add IRR & NPV to Pivot Table as Calculated Field

    OK. Am I right, if I assume that you are not using PowerPivot, but a regular pivot table with formulas next to the table?

  5. #5
    Board Regular
    Join Date
    Oct 2005
    Posts
    161

    Default Re: Add IRR & NPV to Pivot Table as Calculated Field

    Hi. Yes, that's correct, regular pivot table....

  6. #6
    Board Regular
    Join Date
    Apr 2012
    Posts
    223

    Default Re: Add IRR & NPV to Pivot Table as Calculated Field

    Have you tried using IFERROR?

  7. #7
    Board Regular
    Join Date
    Oct 2005
    Posts
    161

    Default Re: Add IRR & NPV to Pivot Table as Calculated Field

    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.

  8. #8
    New Member
    Join Date
    Oct 2012
    Posts
    2

    Default Re: Add IRR & NPV to Pivot Table as Calculated Field

    Quote Originally Posted by Laurent C View Post
    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.

  9. #9
    New Member
    Join Date
    Oct 2012
    Posts
    2

    Default Re: Add IRR & NPV to Pivot Table as Calculated Field

    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.

  10. #10
    Board Regular
    Join Date
    Apr 2012
    Posts
    223

    Default Re: Add IRR & NPV to Pivot Table as Calculated Field

    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).

Page 1 of 2 12 LastLast

Like this thread? Share it with others

Like this thread? Share it with others

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts
  •  


DMCA.com