+ Reply to Thread
Results 1 to 6 of 6

Index with multiple match criteria (3 and more)

  1. #1
    Registered User
    Join Date
    01-26-2018
    Location
    Paris
    MS-Off Ver
    O365 (PC) v.2202
    Posts
    12

    Lightbulb Index with multiple match criteria (3 and more)

    Hi y'all!

    Here is what I have:

    I have 20 cities.

    For cities, I calculated labor costs, acquisition costs, rent expenses, and many more. They are calculated in a single sheet called Inputs.

    Here is how it is organized:

    Section 1:
    Header: Labor costs (A1)
    List of 20 cities: Paris to Marseille (B3 to B22)

    Section 2:
    Header: Acquisitions costs (A25)
    List of 20 cities: Paris to Marseille (B27 to B46)

    Section 3:
    etc. for rent expenses and other sections

    In the columns, I have dates (2021/2022/2023/2024) or monthly (2021-2024)

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

    What I want to tell excel is that :

    Go to the previously mentioned 'Input' sheet and Match "labor costs", then once you've located it, move to the below range and match the city, then Match date in cols and return the value

    So I can get my results in the 'Output' sheet in the following manner :

    Header: Paris (A1)

    List of variables: Labor costs, Acquisition costs, Rent expenses, etc. (B3:B7)

    Dates in columns (C2:F2)

    And my matched numbers C3:F7


    Attached, is a mock template articulating the question.


    Many thanks !
    Attached Files Attached Files

  2. #2
    Forum Expert
    Join Date
    05-05-2015
    Location
    UK
    MS-Off Ver
    Microsoft Excel for Microsoft 365 MSO (Version 2402 Build 16.0.17328.20068) 64-bit
    Posts
    28,144

    Re: Index with multiple match criteria (3 and more)

    in C6

    =SUMPRODUCT((INDEX(Inputs!$E$1:$K$303,MATCH(Outputs!$B6,Inputs!$C$1:$C$303,0)+MATCH(Outputs!$B$3,Inputs!$D$1:$D$303,0)-3,0))*(Inputs!$E$35:$K$35=Outputs!C$5))

    OR

    =INDEX(Inputs!$E$1:$K$303,MATCH(Outputs!$B7,Inputs!$C$1:$C$303,0)+MATCH(Outputs!$B$3,Inputs!$D$1:$D$303,0)-3,MATCH(C$5,Inputs!$E$35:$K$35,0))

    Copy across and down

    in C15

    =SUMPRODUCT((INDEX(Inputs!$E$1:$CJ$303,MATCH(Outputs!$B15,Inputs!$C$1:$C$303,0)+MATCH(Outputs!$B$3,Inputs!$D$1:$D$303,0)-3,0))*(Inputs!$E$7:$CJ$7=Outputs!C$14))

    OR

    =INDEX(Inputs!$E$1:$CJ$303,MATCH(Outputs!$B16,Inputs!$C$1:$C$303,0)+MATCH(Outputs!$B$3,Inputs!$D$1:$D$303,0)-3,MATCH(C$14,Inputs!$E$7:$CJ$7,0))

    in B3

    Data validation list called "Cities"

    Please ensure titles in Outputs match those in Inputs : I adjusted some

    NOTE: I added additional rows in INPUTS to ensure rows between headings in column C and City rows is CONSTANT so use attached file.
    Attached Files Attached Files
    Last edited by JohnTopley; 06-21-2022 at 01:33 PM.
    If that takes care of your original question, please select Thread Tools from the menu link above and mark this thread as SOLVED.

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

    Re: Index with multiple match criteria (3 and more)

    Outputs

    C6=IFERROR(IF($B6<>"",SUMIFS(INDEX(Inputs!$D$8:$CJ$275,,MATCH(Outputs!C$5,Inputs!$D$34:$J$34,0)),Inputs!$C$8:$C$275,Outputs!$B$3,Inputs!$A$8:$A$275,Outputs!$B6),""),"")

    Copy across and down


    C15=IFERROR(IF($B15<>"",SUMIFS(INDEX(Inputs!$D$8:$CJ$275,,MATCH(Outputs!C$14,Inputs!$D$7:$CI$7,0)),Inputs!$C$8:$C$275,Outputs!$B$3,Inputs!$A$8:$A$275,Outputs!$B15),""),"")

    Copy across and down


    I changed the file structure

    The cities are selectable from the drop down list in B3
    Attached Files Attached Files

  4. #4
    Forum Expert
    Join Date
    05-30-2012
    Location
    The Netherlands
    MS-Off Ver
    Office 365
    Posts
    14,987

    Re: Index with multiple match criteria (3 and more)

    With a pivot table (for the annual data).

    See the attached file.
    Notice my main language is not English.

    I appreciate it, if you reply on my solution.

    If you are satisfied with the solution, please mark the question solved.

    You can add reputation by clicking on the star * add reputation.

  5. #5
    Registered User
    Join Date
    01-26-2018
    Location
    Paris
    MS-Off Ver
    O365 (PC) v.2202
    Posts
    12

    Re: Index with multiple match criteria (3 and more)

    Thanks to all of you. I implemented the first one, gonna try the two others for the learning.

    Many thanks for your time

  6. #6
    Forum Expert
    Join Date
    05-30-2012
    Location
    The Netherlands
    MS-Off Ver
    Office 365
    Posts
    14,987

    Re: Index with multiple match criteria (3 and more)

    Glad I could help.

    If you are satisfied with the solution, please mark the question solved.

    You can add reputation by clicking on the star * add reputation.

+ 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. [SOLVED] Index Match help for multiple criteria match in a range of cells
    By GordonKy42 in forum Excel Formulas & Functions
    Replies: 3
    Last Post: 07-01-2021, 08:50 AM
  2. VBA function to match multiple criteria faster than vlookup or index match
    By bkav1991 in forum Excel Programming / VBA / Macros
    Replies: 15
    Last Post: 11-09-2020, 09:14 AM
  3. Replies: 1
    Last Post: 03-25-2020, 08:06 AM
  4. Replies: 1
    Last Post: 03-01-2020, 10:36 PM
  5. Replies: 16
    Last Post: 01-05-2018, 11:04 PM
  6. Need help in Index, Match usage to match multiple criteria in sum function
    By Summer0830 in forum Excel Formulas & Functions
    Replies: 6
    Last Post: 03-26-2017, 02:47 AM
  7. Replies: 2
    Last Post: 09-27-2014, 04:34 PM

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