Forum

Notifications
Clear all

GETPIVOTDATA With Nested ROW

2 Posts
2 Users
0 Reactions
190 Views
Philip Treacy
(@philipt)
Posts: 1629
Member Admin
Topic starter
 

                   Hello Anders;

                In  workbook attached below,  - In worksheet - correct Layout  and GPD  - Mynda worksheet in GETPIVOTDATA with ROW formula, what is 
                 Row (A1) refers to ?.

                In DATA for 2017 worksheet  I  have written GETPIVOTDATA formulas , but for every month from Jan to Dec. I had to change month. I am 
                 struggling since 1 hour  and entering following formula in cell J122 to make it dynamic ,  and keep making some revisions to this formula
 

                = GETPIVOTDATA("Sum of Sales", $I$5, MONTH(I7), TEXT(DATE(1904,ROW(A1),1)))

                        Keep getting error message " entered too few arguments for this function",  what I  am doing wrong ?

                          I  like to learn Getpivotdata with Row function nested ? 

                      Thank you very much.  Have a great day.

                   Sincerely;
     

                   Mitul.

 
Posted : 28/05/2018 6:07 am
Anders Sehlstedt
(@sehlsan)
Posts: 968
Prominent Member
 

Hello Mitul,

This question is not related to this post, so you should have created a new topic.

Anyway, the answer to your first question is that the ROW(A1) embedded in the formula in cell H23 (shown below) is fetching the row number for the cell, which is 1, so the date function gets 1 for the month section. When you copy the formula down the row reference will now be ROW(A2), resulting in 2. This is a way to get a month value from 1 to 12. It doesn't matter if you change A1 to ZZ1, as long as you stay on first row of the sheet you will get 1 as a result.

=GETPIVOTDATA("Value";$G$1; "MONTH"; TEXT(DATE(1904;ROW(A1);1);"mmmm"); "Year"; "2016")

A tip here. Even though this formula works fine for you, it doesn't for me and some other European users. I get a #REF! error because of two reasons.
1) Formatting text using lowercase m instead of uppercase M results in Excel to format the numbers as minutes.
2) Even though correcting this and using uppercase M to format the text to show the months name, I will get the spelling as it is in Sweden, which also will give me a #REF! error.

If you are to share such files globally, I do recommend that you in formulas as this also include a language code in which the text is to be formatted to. The below formula will work for anyone, regardless of where they are in the world.

=GETPIVOTDATA("Value";$G$1; "MONTH"; TEXT(DATE(1904;ROW(A1);1);"[$-en-GB]MMMM"); "Year";"2016")

As you can see, I have added [$-en-GB] in the text formatting rule, which in this case will give me the month name in English.

----------------

Your second question. In cell J122 in sheet "Data for 2017" you have this formula:
= GETPIVOTDATA("Sum of Sales", $I$5, MONTH(I7), TEXT(DATE(1904,ROW(A1),1)))

There are three errors in this formula.
The first one is where you have typed in MONTH(I7).
The second is that the TEXT() function is incomplete.
The third is that you have missed to add from which column you want the data from in the PivotTable.

If you copy below formula and paste it in cell J122 you will get the data and you can copy the formula down and you will get correct data for each month.
= GETPIVOTDATA("Sum of Sales"; $I$5; "Month"; TEXT(DATE(1904;ROW(A1);1);"[$-en-GB]MMM");"Region";J$121)

Have a great day ahead!

Br,
Anders

 
Posted : 28/05/2018 5:03 pm
Share: