+ Reply to Thread
Results 1 to 7 of 7

How to optimize Index Match for huge dataset

  1. #1
    Registered User
    Join Date
    06-15-2019
    Location
    Seattle
    MS-Off Ver
    2017
    Posts
    3

    How to optimize Index Match for huge dataset

    Hi all,

    I have a working formula but I now want to use it to search across a large dataset so I need to optimize the formula.
    I am trying to use index match to look for value in table 2.
    But my current dataset has 0.5m rows which it take forever to do the calculation and crashing now and again...

    My index match formula: =INDEX($F$3:$I$7,MATCH($A3,$F$3:$F$7,0),MATCH($B$2,$F$2:$I$2,0))
    Couldn't attached, so please find the sample data set below.
    I am looking for value, value1, and value2 in Table 2 by using the Number column in table 1.

    Table 1
    Number value value1 value2 (index match for the value, value1, value2)
    5
    3
    2
    1
    4

    Table 2
    number value value1 value2
    1 asfd 2341 a23roij
    2 asdf 32q54 qwejfkds
    3 adsfb 34qfrv 23frd
    4 dfew 45twgefs 23ew
    5 qewrf 34f 23eww


    Is there any way this kind of search can be run on this scale?

    Thank you.

  2. #2
    Forum Expert shg's Avatar
    Join Date
    06-20-2007
    Location
    The Great State of Texas
    MS-Off Ver
    2003, 2010
    Posts
    40,678

    Re: How to optimize Index Match for huge dataset

    Sort the table by the top row and leftmost column, then use a range lookup (change the last MATCH argument to 1).
    Entia non sunt multiplicanda sine necessitate

  3. #3
    Registered User
    Join Date
    06-15-2019
    Location
    Seattle
    MS-Off Ver
    2017
    Posts
    3

    Re: How to optimize Index Match for huge dataset

    Hi shg,

    Thanks for your reply.
    I sorted the number column from small to large on both table and change the formula to =INDEX($F$3:$I$7,MATCH($A3,$F$3:$F$7,0),MATCH($B$2,$F$2:$I$2,1)) as you said the last MATCH argument to 1.
    But the value returned are actually wrong. Am I doing anything incorrectly?
    Also, the number on table 1 might not exist on table 2. Would it impact?

  4. #4
    Forum Guru
    Join Date
    04-13-2005
    Location
    North America
    MS-Off Ver
    2002/XP and 2007
    Posts
    15,832

    Re: How to optimize Index Match for huge dataset

    What was the lookup value? What were the values in the first row of the lookup table? Were they sorted left to right in ascending order or descending order? What column number did the MATCH() function return (use the Evaluate Formula tool: https://support.office.com/en-us/art...6-a70aa409b8a7 )? What column number should it have returned?
    Quote Originally Posted by shg
    Mathematics is the native language of the natural world. Just trying to become literate.

  5. #5
    Registered User
    Join Date
    06-15-2019
    Location
    Seattle
    MS-Off Ver
    2017
    Posts
    3

    Re: How to optimize Index Match for huge dataset

    Hi MrShorty,

    I have attached the sample file.
    Column B is lookup value from G, C from H, and D from I.
    I am only sorting the first column on each table. I didn't sort the left to right, but it's in same order.
    Attached Files Attached Files

  6. #6
    Forum Guru
    Join Date
    04-13-2005
    Location
    North America
    MS-Off Ver
    2002/XP and 2007
    Posts
    15,832

    Re: How to optimize Index Match for huge dataset

    I am not sure I understand the question. Your lookup table (F2:I7) is set up exactly as shg suggested with the left column (column F) sorted in ascending order and the first row (G2:I2) also sorted in ascending order. Recognizing that these are dummy values, perhaps they are not sorted in your original lookup table, but I assume you are able to sort the table like your sample file.

    With column F and row 2 sorted in ascending order, as shg suggested, it should be a simple matter to replace the 0's in each MATCH() function with 1's I edited the formula in C3 to be
    Formula: copy to clipboard
    Please Login or Register  to view this content.
    (note the additional change to the absolute referencing for the C2 lookup value reference in the 2nd MATCH() function) and it seemed to work just fine. What about your sample file does not accurately represent your true file? What questions do you have about this kind of lookup?

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

    Re: How to optimize Index Match for huge dataset

    If columns are in the same order then
    B3
    =INDEX(G$3:G$7,MATCH($A3,$F$3:$F$7,1))
    But if the number on table 1 might not exist on table 2, it still give result from big number that less than lookup value.

    or try
    =LOOKUP(1,1/($F$3:$F$7=$A3),G$3:G$7)
    Attached Files Attached Files

+ 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. How to optimize Index Match , for large sets of data
    By asweare in forum Excel Programming / VBA / Macros
    Replies: 18
    Last Post: 12-29-2018, 12:46 PM
  2. Index match equivalent in VBA for large dataset?
    By jhuvba in forum Excel Programming / VBA / Macros
    Replies: 8
    Last Post: 04-26-2018, 11:49 PM
  3. Replies: 3
    Last Post: 10-20-2017, 12:40 AM
  4. Huge data index/match replacement
    By teireii in forum Excel Programming / VBA / Macros
    Replies: 6
    Last Post: 07-31-2017, 03:33 AM
  5. Huge data index/match replacement
    By teireii in forum Excel Formulas & Functions
    Replies: 1
    Last Post: 07-26-2017, 05:44 AM
  6. index-match between two huge files
    By is2_egypt in forum Excel Formulas & Functions
    Replies: 3
    Last Post: 09-15-2016, 09:59 AM
  7. Replies: 2
    Last Post: 08-30-2014, 02:49 AM

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