+ Reply to Thread
Results 1 to 9 of 9

Pivot table of month-end closing prices

  1. #1
    Registered User
    Join Date
    06-28-2010
    Location
    Tampa Bay, FL
    MS-Off Ver
    Excel 365
    Posts
    13

    Pivot table of month-end closing prices

    I have over 20 years of daily closing prices for a given stock. How do i create a pivot table of month-end closes? Thanking you, in advance.

  2. #2
    Forum Moderator alansidman's Avatar
    Join Date
    02-02-2010
    Location
    Steamboat Springs, CO
    MS-Off Ver
    MS Office 365 Version 2405 Win 11 Home 64 Bit
    Posts
    23,872

    Re: Pivot table of month-end closing prices

    Attached is a mocked up scenario. Column A is consecutive dates. Column B is Price. Column C is formula to find End of Month. Column D is formula to test if Column A equals Column C. Build pivot with the data in this format. See attached file
    Attached Files Attached Files
    Alan עַם יִשְׂרָאֵל חַי


    Change an Ugly Report with Power Query
    Database Normalization
    Complete Guide to Power Query
    Man's Mind Stretched to New Dimensions Never Returns to Its Original Form

  3. #3
    Registered User
    Join Date
    06-28-2010
    Location
    Tampa Bay, FL
    MS-Off Ver
    Excel 365
    Posts
    13

    Re: Pivot table of month-end closing prices

    Thank you. The last trade date is not always the last day of the month. It is easy to find the last trade date in steps in excel, I was looking for a way to do it in a pivot table, in the same way you can find, say, the year high and year low. See attached.
    Attached Files Attached Files

  4. #4
    Forum Guru
    Join Date
    08-28-2014
    Location
    USA
    MS-Off Ver
    Excel 2019
    Posts
    17,546

    Re: Pivot table of month-end closing prices

    Inspired by Alan's suggestion:
    1. Add a column (I) to the data populated using: =MONTH(A3)<>MONTH(A4)
    2. Use the new column as a filter for the pivot table.
    Let us know if you have any questions.
    Consider taking the time to add to the reputation of everybody that has taken the time to respond to your query.

  5. #5
    Registered User
    Join Date
    06-28-2010
    Location
    Tampa Bay, FL
    MS-Off Ver
    Excel 365
    Posts
    13

    Re: Pivot table of month-end closing prices

    Thank you all. As I said in my original post, this is easy in excel. See attached for an explicit description of my request. It appears it cannot be done in a pivot table alone without a helper column.
    Attached Files Attached Files

  6. #6
    Forum Expert XOR LX's Avatar
    Join Date
    04-18-2013
    Location
    Turin, Italy
    MS-Off Ver
    Office 365
    Posts
    7,742

    Re: Pivot table of month-end closing prices

    Hi,

    If you add your Pivot Table to the data model then you can achieve what you want with the following measure:

    PHP Code: 
    SPY Close :=
    VAR 
    CurrentDate =
        
    MAX Range[Date] )
    VAR 
    LatestDateinMonth =
        
    CALCULATE (
            
    MAX Range[Date] ),
            
    FILTER (
                
    ALL Range ),
                
    Range[Date] > EOMONTH CurrentDate, -)
                    && 
    Range[Date] <= EOMONTH CurrentDate)
            )
        )
    RETURN
        
    CALCULATE MAX Range[SPY] ), Range[Date] = LatestDateinMonth 
    Replace Range in the above with the name of your table.

    Regards
    Click * below if this answer helped

    Advanced Excel Techniques: http://excelxor.com/

  7. #7
    Forum Guru Bo_Ry's Avatar
    Join Date
    09-10-2018
    Location
    Thailand
    MS-Off Ver
    MS 365
    Posts
    7,211

    Re: Pivot table of month-end closing prices

    Create Table1

    Insert Pivot > check add this data to the data model

    Power Pivot > New Measure

    =MAXX(TOPN(1,Table1,[Date],DESC),[SPY])
    Attached Files Attached Files

  8. #8
    Registered User
    Join Date
    06-28-2010
    Location
    Tampa Bay, FL
    MS-Off Ver
    Excel 365
    Posts
    13

    Re: Pivot table of month-end closing prices

    THIS is it! Thank you.

  9. #9
    Forum Moderator alansidman's Avatar
    Join Date
    02-02-2010
    Location
    Steamboat Springs, CO
    MS-Off Ver
    MS Office 365 Version 2405 Win 11 Home 64 Bit
    Posts
    23,872

    Re: Pivot table of month-end closing prices

    If that takes care of your original question, please select Thread Tools from the menu link above and mark this thread as SOLVED.

    Also, you may not be aware that you can thank those who have helped you by clicking the small star icon located in the lower left corner of the post in which the help was given. By doing so you can add to the reputation(s) of those who helped.

+ Reply to Thread

Thread Information

Users Browsing this Thread

There are currently 1 users browsing this thread. (0 members and 1 guests)

Similar Threads

  1. Replies: 3
    Last Post: 11-06-2019, 03:41 PM
  2. Change Pivot Table Fields Month by Month Automatically
    By phoebeyanan in forum Excel Programming / VBA / Macros
    Replies: 1
    Last Post: 08-16-2017, 04:03 PM
  3. Pivot Table Product Prices
    By dw_22801 in forum Excel Charting & Pivots
    Replies: 2
    Last Post: 08-18-2016, 01:14 PM
  4. Replies: 0
    Last Post: 02-04-2015, 11:38 AM
  5. [SOLVED] Pivot Table Not Grouping by Month for Latest Month (groups > 7/20/2013)
    By justforthis1 in forum Excel Charting & Pivots
    Replies: 7
    Last Post: 09-04-2013, 12:28 PM
  6. Replies: 3
    Last Post: 10-30-2012, 09:21 AM
  7. Get closing stock prices from outside data source
    By maacmaac in forum Excel Programming / VBA / Macros
    Replies: 2
    Last Post: 10-31-2008, 02:36 PM

Tags for this Thread

Bookmarks

Posting Permissions

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

Search Engine Friendly URLs by vBSEO 3.6.0 RC 1