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.
 

Domenic

MrExcel MVP
Joined
Mar 10, 2004
Messages
19,013
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)))
 

Domenic

MrExcel MVP
Joined
Mar 10, 2004
Messages
19,013
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:

Forum statistics

Threads
1,082,250
Messages
5,364,020
Members
400,774
Latest member
Goldi paul

Some videos you may like

This Week's Hot Topics

  • populate from drop list with multiple tables
    Hi All, i have a drop list that displays data, what i want is when i select one of those from the list to populate text from different tables on...
  • Find list of words from sheet2 in sheet1 before a comma and extract text vba
    Hi Friends, Trying to find the solution on my task. But did not find suitable one to the need. Here is my query and sample file with details...
  • Dynamic Formula entry - VBA code sought
    Hello, really hope one of you experts can help with this - i've spent hours on this and getting no-where. .I have a set of data (more rows than...
  • Listbox Header
    Have a named range called "AccidentsHeader" Within my code I have: [CODE]Private Sub CommandButton1_Click() ListBox1.RowSource =...
  • Complex Heat Map using conditional formatting
    Good day excel world. I have a concern. Below link have a list of countries that carries each country unique data. [URL...
  • Conditional formatting
    Hi good morning, hope you can help me please, I have cells P4:P54 and if this cell is equal to 1 then i want row O to say "Fully Utilised" and to...
Top