XIRR Selecting Multiple arrays

mbdeming

New Member
Joined
May 27, 2009
Messages
4
I am trying to calculate the IRR for a series of cash flows and dates and wanted to use the XIRR function. My issue is that my data isn't necessarily lined up for selecting across one array. I have it running horizontal from Left to right then back on the left side of the page running across to the right. Is there any way to group both the values and dates so that I can calculate the IRR without reworking the format? Thanks in advance for your help.
 

Excel Facts

Excel Can Read to You
Customize Quick Access Toolbar. From All Commands, add Speak Cells or Speak Cells on Enter to QAT. Select cells. Press Speak Cells.
For simplicity, let's assume the following...

B2:IV2 contains the date and B3:IV3 contains the corresponding values

B5:IV5 contains the date and B6:IV6 contains the corresponding values

B8:IV8 contains the date and B9:IV9 contains the corresponding values

Then try the following formulas, which need to be confirmed with CONTROL+SHIFT+ENTER, not just ENTER...

IRR:

Code:
=IRR(N(OFFSET(B2:IV9,INT((ROW(INDIRECT("1:"&(INT(ROWS(B2:IV9)/3)+1)*
   COLUMNS(B2:IV9)))-1)/COLUMNS(B2:IV9))*3+1,
      MOD((ROW(INDIRECT("1:"&(INT(ROWS(B2:IV9)/3)+1)*
         COLUMNS(B2:IV9)))-1),COLUMNS(B2:IV9)),1,1)))

XIRR:

Code:
=XIRR(N(OFFSET(B2:IV9,INT((ROW(INDIRECT("1:"&(INT(ROWS(B2:IV9)/3)+1)*
  COLUMNS(B2:IV9)))-1)/COLUMNS(B2:IV9))*3+1,
       MOD((ROW(INDIRECT("1:"&(INT(ROWS(B2:IV9)/3)+1)*
            COLUMNS(B2:IV9)))-1),COLUMNS(B2:IV9)),1,1)),
                 N(OFFSET(B2:IV9,INT((ROW(INDIRECT("1:"&(INT(ROWS(B2:IV9)/
                      3)+1)*COLUMNS(B2:IV9)))-1)/COLUMNS(B2:IV9))*3,
                         MOD((ROW(INDIRECT("1:"&(INT(ROWS(B2:IV9)/3)+1)*
                              COLUMNS(B2:IV9)))-1),COLUMNS(B2:IV9)),1,1)))
 
Upvote 0
As per your email, I see that your data is laid out as follows...

D2, F2, H2, through AZ2 contain the date and D14, F14, H14, through AZ14 contain the corresponding values

D19, F19, H19, through AX19 contain the date and D31, F31, H31, through AX31 contain the corresponding values

In this case, try the following formula that needs to be confirmed with CONTROL+SHIFT+ENTER...

Code:
=XIRR(N(OFFSET(D2:AZ31,
   INT((ROW(INDIRECT("1:"&(INT(COLUMNS(D2:AZ31)/2)+1)*
   (INT(ROWS(D2:AZ31)/17)+1)))*2-2)/((INT(COLUMNS(D2:AZ31)/2)+1)*
   (INT(ROWS(D2:AZ31)/17)+1)))*17+12,MOD(ROW(INDIRECT("1:"&
   (INT(COLUMNS(D2:AZ31)/2)+1)*(INT(ROWS(D2:AZ31)/17)+1)))*2-2,
   (INT(COLUMNS(D2:AZ31)/2)+1)*(INT(ROWS(D2:AZ31)/17)+1)),1,1)),
   N(OFFSET(D2:AZ31,INT((ROW(INDIRECT("1:"&(INT(COLUMNS(D2:AZ31)/2)+1)*
   (INT(ROWS(D2:AZ31)/17)+1)))*2-2)/((INT(COLUMNS(D2:AZ31)/2)+1)*
   (INT(ROWS(D2:AZ31)/17)+1)))*17,MOD(ROW(INDIRECT("1:"&
   (INT(COLUMNS(D2:AZ31)/2)+1)*(INT(ROWS(D2:AZ31)/17)+1)))*2-2,
   (INT(COLUMNS(D2:AZ31)/2)+1)*(INT(ROWS(D2:AZ31)/17)+1)),1,1)))

As you can see, the formula is very complex. For this reason, I suggest you re-format your data.
 
Last edited:
Upvote 0

Forum statistics

Threads
1,214,651
Messages
6,120,738
Members
448,988
Latest member
BB_Unlv

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