+ Reply to Thread
Results 1 to 4 of 4

Use a Pivot table to work out average order value of invoices

Hybrid View

  1. #1
    Registered User
    Join Date
    05-17-2024
    Location
    Belfast
    MS-Off Ver
    Microsoft 365
    Posts
    2

    Use a Pivot table to work out average order value of invoices

    I have sales invoice/credit note data and I want to find out the average order value for any given month. My report has multiple lines per invoice, as some invoices may have more than one product. I have tried to work out the value using a pivot table but the results are skewed due to the count of the multiple lines on certain invoices.

    I'd be glad of any help on what fields or functions to choose in the pivot table as I can't seem to get the answer I'm looking for.

    Thanks!
    Attached Files Attached Files
    Last edited by Melissa_8; 05-17-2024 at 09:27 AM.

  2. #2
    Forum Moderator AliGW's Avatar
    Join Date
    08-10-2013
    Location
    Retired in Ipswich, Suffolk, but grew up in Sawley, Derbyshire (both in England)
    MS-Off Ver
    MS 365 Subscription Insider Beta Channel v. 2503 (Windows 11 Home 24H2 64-bit)
    Posts
    90,377

    Re: Use a Pivot table to work out average order value of invoices

    Welcome to the forum.

    With the date 01/03/2024 in P1, try this in M2:

    =LET(u,UNIQUE(A2:B21),f,FILTER(u,(INDEX(u,,2)>=P1)*(INDEX(u,,2)<EDATE(P1,1))),AVERAGE(MAP(INDEX(f,,1),INDEX(f,,2),LAMBDA(i,d,SUMPRODUCT((A2:A21=i)*(B2:B21=d)*J2:J21)))))

    Does it produce your expected result? If not, what should the expected result be?
    Attached Files Attached Files
    Ali


    Enthusiastic self-taught user of MS Excel who's always learning!
    Don't forget to say "thank you" in your thread to anyone who has offered you help. It's a universal courtesy.
    You can reward them by clicking on * Add Reputation below their user name on the left, if you wish.

    NB:
    as a Moderator, I never accept friendship requests.
    Forum Rules (updated August 2023): please read them here.

  3. #3
    Registered User
    Join Date
    05-17-2024
    Location
    Belfast
    MS-Off Ver
    Microsoft 365
    Posts
    2

    Re: Use a Pivot table to work out average order value of invoices

    Hello Ali,

    Thanks for the welcome!

    The formula gives the expected result, thank you very much!

  4. #4
    Forum Moderator AliGW's Avatar
    Join Date
    08-10-2013
    Location
    Retired in Ipswich, Suffolk, but grew up in Sawley, Derbyshire (both in England)
    MS-Off Ver
    MS 365 Subscription Insider Beta Channel v. 2503 (Windows 11 Home 24H2 64-bit)
    Posts
    90,377

    Re: Use a Pivot table to work out average order value of invoices

    If you paste this into M4, it will show what the formula is calculating from:

    =LET(u,UNIQUE(A2:B21),f,FILTER(u,(INDEX(u,,2)>=P1)*(INDEX(u,,2)<EDATE(P1,1))),HSTACK(f,MAP(INDEX(f,,1),INDEX(f,,2),LAMBDA(i,d,SUMPRODUCT((A2:A21=i)*(B2:B21=d)*J2:J21)))))
    Glad to have helped.

    If that takes care of your original question, please choose Thread Tools from the menu link above and mark this thread as SOLVED. You can also access the SOLVED tag by editing the opening post and choosing SOLVED from the drop-down to the left of the title box.

    Also, if you have not already done so, remember that you can reward anyone who offered you help towards a solution for your issue by clicking the small star icon (* Add Reputation) 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 each of those who offered help.

+ 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: 10
    Last Post: 11-09-2021, 04:21 AM
  2. How to order columns of Pivot table in correct month order
    By Cordelia123 in forum Excel Charting & Pivots
    Replies: 0
    Last Post: 04-23-2021, 08:29 AM
  3. Want Pivot table's average to show average by number of month.
    By jp16 in forum Excel Charting & Pivots
    Replies: 3
    Last Post: 07-16-2019, 06:07 AM
  4. Filter Pivot table by each customer and auto email invoices unpaid
    By whatsup in forum Excel Programming / VBA / Macros
    Replies: 7
    Last Post: 05-04-2019, 09:21 PM
  5. Replies: 4
    Last Post: 09-26-2017, 12:41 PM
  6. Pivot table for past due invoices by Customer
    By kpierce in forum Excel Charting & Pivots
    Replies: 2
    Last Post: 02-24-2015, 01:31 PM
  7. Open Word Work Order Template with excel generated work order #
    By Tivka in forum Excel Programming / VBA / Macros
    Replies: 0
    Last Post: 11-26-2012, 02:24 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