+ Reply to Thread
Results 1 to 11 of 11

Sum or Sumproduct or ? with dates in the table headers

  1. #1
    Registered User
    Join Date
    08-19-2015
    Location
    London, England
    MS-Off Ver
    365
    Posts
    67

    Sum or Sumproduct or ? with dates in the table headers

    Hi, I hope someone can help me with this...

    I have a table with dates in the headers, rows with fruit products sold in different countries and I'm trying to sum f.i. total Apples sold in the UK as well as FR, based on 40 (iso weeknumber) and later 10 (being the month oct.).

    I've tries different variations om sumproduct and sumifs but I only get #value results.

    Many thanks in advance for helping me out....

    example.png
    Attached Files Attached Files

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

    Re: Sum or Sumproduct or ? with dates in the table headers

    In the workbook you ask this:

    What formula would I need to sum the total amount of Apples sold in DE and FR in week 40 (2-8 okt 2023), or f.i. the total amount of Oranges sold in FR, IT and UK.
    Try this:

    =SUMPRODUCT((((Tabel1[Country]="UK")+(Tabel1[Country]="FR")+(Tabel1[Country]="IT"))*(Tabel1[Product]="Apples"))*(ISOWEEKNUM(Tabel1[[#Headers],[1-10-2023]:[10-10-2023]])=40)*Tabel1[[1-10-2023]:[10-10-2023]])
    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.
    You can reward them by clicking on * Add Reputation below their user name on the left, if you wish.

    Forum Rules (updated August 2023): please read them here.

  3. #3
    Forum Moderator AliGW's Avatar
    Join Date
    08-10-2013
    Location
    Retired in Ipswich, Suffolk, but grew up in Sawley, Derbyshire (England)
    MS-Off Ver
    MS 365 Subscription Insider Beta Channel v. 2404 (Windows 11 22H2 64-bit)
    Posts
    80,838

    Re: Sum or Sumproduct or ? with dates in the table headers

    And for the same, but in October:

    =SUMPRODUCT((((Tabel1[Country]="UK")+(Tabel1[Country]="FR")+(Tabel1[Country]="IT"))*(Tabel1[Product]="Apples"))*(MONTH(Tabel1[[#Headers],[1-10-2023]:[10-10-2023]])=10)*Tabel1[[1-10-2023]:[10-10-2023]])

  4. #4
    Registered User
    Join Date
    08-19-2015
    Location
    London, England
    MS-Off Ver
    365
    Posts
    67

    Re: Sum or Sumproduct or ? with dates in the table headers

    Wow..! Thanks ever so much for your help AliGW...

    Thing I missed out on in my formulas were:
    (Tabel1[Country]="UK")+(Tabel1[Country]="FR")+(Tabel1[Country]="IT").
    I used * instead of +.

    ISOWEEKNUM(Tabel1[[#Headers],[1-10-2023]:[10-10-2023]])=40
    MONTH(Tabel1[[#Headers],[1-10-2023]:[10-10-2023]])=10
    I just couldn't get these right with the above mentioned * instead of +

  5. #5
    Forum Moderator AliGW's Avatar
    Join Date
    08-10-2013
    Location
    Retired in Ipswich, Suffolk, but grew up in Sawley, Derbyshire (England)
    MS-Off Ver
    MS 365 Subscription Insider Beta Channel v. 2404 (Windows 11 22H2 64-bit)
    Posts
    80,838

    Re: Sum or Sumproduct or ? with dates in the table headers

    Happy to help.

    + means OR, * means AND in these scenarios.

  6. #6
    Registered User
    Join Date
    08-19-2015
    Location
    London, England
    MS-Off Ver
    365
    Posts
    67

    Re: Sum or Sumproduct or ? with dates in the table headers

    Now that I'm adding the formula to my actual sheet a question arises:
    Can I somehow replace the TTabel1[[#Headers],[1-10-2023]:[10-10-2023]] part so that it automatically expands when the table gets one or more new columns...?

    I've tried:
    Tabel1[[#Headers]:[#Headers]]
    Tabel1[[#Headers],[#Headers]:[#Headers]] but that obviously doesn't work.

    Another option could be to add a 'last column' and copy/paste new data before that, but I'm not sure whoever handling the file would understand.

    Like:
    Tabel1[[#Headers],[1-10-2023]:[Last Column]]

  7. #7
    Forum Moderator AliGW's Avatar
    Join Date
    08-10-2013
    Location
    Retired in Ipswich, Suffolk, but grew up in Sawley, Derbyshire (England)
    MS-Off Ver
    MS 365 Subscription Insider Beta Channel v. 2404 (Windows 11 22H2 64-bit)
    Posts
    80,838

    Re: Sum or Sumproduct or ? with dates in the table headers

    The second option would be your best bet, I think.

  8. #8
    Forum Expert
    Join Date
    09-25-2015
    Location
    Milan Italy
    MS-Off Ver
    office 365
    Posts
    1,781

    Re: Sum or Sumproduct or ? with dates in the table headers

    P3=SUMPRODUCT(($C$2:$C$100=$O3)*(VALUE($D$1:$M$1)>=VALUE($P$1))*(VALUE($D$1:$M$1)<=VALUE($Q$1))*(ISNUMBER(MATCH($B$2:$B$100,$T3:$X3,0)))*($D$2:$M$100))

    Copy down
    Attached Files Attached Files

  9. #9
    Registered User
    Join Date
    08-19-2015
    Location
    London, England
    MS-Off Ver
    365
    Posts
    67

    Re: Sum or Sumproduct or ? with dates in the table headers

    Hi Caracalla,

    Thanks, that's an interesting approach which I'm sure I'm gonna use some day, but for now I'll go with AliGW's sollution...

  10. #10
    Forum Moderator AliGW's Avatar
    Join Date
    08-10-2013
    Location
    Retired in Ipswich, Suffolk, but grew up in Sawley, Derbyshire (England)
    MS-Off Ver
    MS 365 Subscription Insider Beta Channel v. 2404 (Windows 11 22H2 64-bit)
    Posts
    80,838

    Re: Sum or Sumproduct or ? with dates in the table headers

    If you have not already done so, you may not be aware that you can thank 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.

  11. #11
    Registered User
    Join Date
    08-19-2015
    Location
    London, England
    MS-Off Ver
    365
    Posts
    67

    Re: Sum or Sumproduct or ? with dates in the table headers

    I did that already for the both of you, haven't you got a rep point from me yesterday..?

+ 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. INDEX SUMPRODUCT to Headers
    By chloeky in forum Excel Formulas & Functions
    Replies: 1
    Last Post: 07-25-2019, 03:44 AM
  2. [SOLVED] SUMPRODUCT on entire columns excluding headers
    By CDN in forum Excel Formulas & Functions
    Replies: 6
    Last Post: 05-05-2019, 08:06 AM
  3. [SOLVED] SumIfs / Sumproduct for table with vertical and horizontal lookup criteria (text+dates)
    By benvass in forum Excel Formulas & Functions
    Replies: 3
    Last Post: 09-17-2018, 10:34 AM
  4. autofilter method of range class failed -header has tables headers and non table headers
    By naveen.acheanz in forum Excel Programming / VBA / Macros
    Replies: 0
    Last Post: 06-16-2016, 08:21 AM
  5. [SOLVED] Sumproduct with date criteria in headers
    By CoachScotticus in forum Excel Formulas & Functions
    Replies: 10
    Last Post: 03-23-2016, 04:41 PM
  6. [SOLVED] How to copy across table headers that are dates?
    By 7:34pm in forum Excel - New Users/Basics
    Replies: 5
    Last Post: 11-17-2015, 02:51 AM
  7. sumproduct with specific column headers
    By PL124006 in forum Excel Formulas & Functions
    Replies: 2
    Last Post: 05-22-2015, 08:33 AM

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