• Skip to main content
  • Skip to header right navigation
  • Skip to site footer

My Online Training Hub

Learn Dashboards, Excel, Power BI, Power Query, Power Pivot

  • Courses
  • Pricing
    • Free Courses
    • Power BI Course
    • Excel Power Query Course
    • Power Pivot and DAX Course
    • Excel Dashboard Course
    • Excel PivotTable Course – Quick Start
    • Advanced Excel Formulas Course
    • Excel Expert Advanced Excel Training
    • Excel Tables Course
    • Excel, Word, Outlook
    • Financial Modelling Course
    • Excel PivotTable Course
    • Excel for Customer Service Professionals
    • Excel for Operations Management Course
    • Excel for Decision Making Under Uncertainty Course
    • Excel for Finance Course
    • Excel Analysis ToolPak Course
    • Multi-User Pricing
  • Resources
    • Free Downloads
    • Excel Functions Explained
    • Excel Formulas
    • Excel Add-ins
    • IF Function
      • Excel IF Statement Explained
      • Excel IF AND OR Functions
      • IF Formula Builder
    • Time & Dates in Excel
      • Excel Date & Time
      • Calculating Time in Excel
      • Excel Time Calculation Tricks
      • Excel Date and Time Formatting
    • Excel Keyboard Shortcuts
    • Excel Custom Number Format Guide
    • Pivot Tables Guide
    • VLOOKUP Guide
    • ALT Codes
    • Excel VBA & Macros
    • Excel User Forms
    • VBA String Functions
  • Members
    • Login
    • Password Reset
  • Blog
  • Excel Webinars
  • Excel Forum
    • Register as Forum Member

GETPIVOTDATA With Nested ROW|General Excel Questions & Answers|Excel Forum|My Online Training Hub

You are here: Home / GETPIVOTDATA With Nested ROW|General Excel Questions & Answers|Excel Forum|My Online Training Hub
Avatar
sp_LogInOut Log In sp_Registration Register
sp_Search Search
Advanced Search|Last Search Results
Search
Forum Scope




Match



Forum Options



Minimum search word length is 3 characters - maximum search word length is 84 characters
sp_Search Search
sp_RankInfo
Lost password?
sp_CrumbsHome HomeExcel ForumGeneral Excel Questions & Answe…GETPIVOTDATA With Nested ROW
sp_PrintTopic sp_TopicIcon
GETPIVOTDATA With Nested ROW
Avatar
MITUL PARIKH
Member
Members
Level 0
Forum Posts: 68
Member Since:
December 8, 2017
sp_UserOfflineSmall Offline
1
May 27, 2018 - 1:41 am
sp_Permalink sp_Print sp_EditHistory

                   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.

Avatar
Anders Sehlstedt
Eskilstuna, Sweden

VIP
Members


Trusted Members
Level 3
Forum Posts: 870
Member Since:
December 7, 2016
sp_UserOfflineSmall Offline
2
May 28, 2018 - 7:03 am
sp_Permalink sp_Print

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

sp_Feed
Go to top
Forum Timezone: Australia/Brisbane
Most Users Ever Online: 245
Currently Online:
Guest(s) 11
Currently Browsing this Page:
1 Guest(s)
Top Posters:
SunnyKow: 1432
Anders Sehlstedt: 870
Purfleet: 412
Frans Visser: 346
David_Ng: 306
lea cohen: 219
A.Maurizio: 202
Jessica Stewart: 202
Aye Mu: 201
jaryszek: 183
Newest Members:
John Chisholm
vexokeb sdfg
John Jack
Malcolm Toy
Ray-Yu Yang
George Shihadeh
Naomi Rumble
Uwe von Gostomski
Jonathan Jones
drsven
Forum Stats:
Groups: 3
Forums: 24
Topics: 6212
Posts: 27236

 

Member Stats:
Guest Posters: 49
Members: 31888
Moderators: 3
Admins: 4
Administrators: Mynda Treacy, Philip Treacy, Catalin Bombea, FT
Moderators: MOTH Support, Velouria, Riny van Eekelen
© Simple:Press —sp_Information

Sidebar

Blog Categories

  • Excel
  • Excel Charts
  • Excel Dashboard
  • Excel Formulas
  • Excel PivotTables
  • Excel Shortcuts
  • Excel VBA
  • General Tips
  • Online Training
  • Outlook
  • Power Apps
  • Power Automate
  • Power BI
  • Power Pivot
  • Power Query
microsoft mvp logo
trustpilot excellent rating
Secured by Sucuri Badge
MyOnlineTrainingHub on YouTube Mynda Treacy on Linked In Mynda Treacy on Instagram Mynda Treacy on Twitter Mynda Treacy on Pinterest MyOnlineTrainingHub on Facebook
 

Company

  • About My Online Training Hub
  • Disclosure Statement
  • Frequently Asked Questions
  • Guarantee
  • Privacy Policy
  • Terms & Conditions
  • Testimonials
  • Become an Affiliate

Support

  • Contact
  • Forum
  • Helpdesk - For Technical Issues

Copyright © 2023 · My Online Training Hub · All Rights Reserved. Microsoft and the Microsoft Office logo are trademarks or registered trademarks of Microsoft Corporation in the United States and/or other countries. Product names, logos, brands, and other trademarks featured or referred to within this website are the property of their respective trademark holders.