+ Reply to Thread
Results 1 to 10 of 10

Optimizing excel formula

  1. #1
    Forum Contributor
    Join Date
    07-22-2013
    Location
    Sibiu
    MS-Off Ver
    Excel 2007
    Posts
    114

    Optimizing excel formula

    Hello,
    I have a workbook that I use to summ up the quantities of "506632" from "vulcom". Lets call 506632 part and vulcom suplier. Of course I have tens of parts and about 10 supliers. The workbook is decent in size but i've had no problems with running it untill I have created a new worksheet to see how much $ we have saved by choosing a suplier over a reference price for that part.

    I am using

    "{=IFERROR(INDEX(Ianuarie;MATCH(506632&"vulCom";Repere_ianuarie&Lista_furnizori_ianuarie;0);4)*INDEX(Sinteza_achizitii!$E:$Q;MATCH(506632&Data_ianuarie;Sinteza_achizitii!$E:$E&Sinteza_achizitii!$G:$G;0);VLOOKUP("Vulcom";Legenda!$H$7:$I$11;2;FALSE));0)}"

    to multiply the quantity of 506632 from Vulcom that we purchased in january (ianuarie) with the price from vulcom in january. Everything works great, problem is that after populating a few hundred cells with this formula the workbook starts to slow down, opens fairly slow and every change takes time to complete.
    1. do you guys have any alternative to index/match
    2. do you think a macro would be faster?
    thank you in advance

  2. #2
    Forum Expert RobertMika's Avatar
    Join Date
    06-22-2009
    Location
    Haverhill, UK
    MS-Off Ver
    Excel 2003-13
    Posts
    1,530

    Re: Optimizing excel formula

    Maybe SUMIFS() for the first part.
    Depends on number of rows you can use VBA and it will be faster.
    Please attached your workbook.
    If you are http://www.excelforum.com/image.php?type=sigpic&userid=125481&dateline=1392355029happy with the results, please add to the contributor's
    reputation by clicking the reputation icon (star icon).




    If you are satisfied with the solution(s) provided, please mark your thread as Solved.
    Select Thread Tools-> Mark thread as Solved.
    To undo, select Thread Tools-> Mark thread as Unsolved.
    http://www.excelaris.co.uk

  3. #3
    Forum Expert
    Join Date
    12-14-2012
    Location
    London England
    MS-Off Ver
    MS 365 Office Suite.
    Posts
    8,448

    Re: Optimizing excel formula

    Why are you using such a complicated formula?

    A relatively simple sum product will do what you need. Entered using ctrl shift enter

    Please Login or Register  to view this content.
    Attached Files Attached Files
    Last edited by mehmetcik; 01-30-2014 at 06:13 AM.

  4. #4
    Forum Contributor
    Join Date
    07-22-2013
    Location
    Sibiu
    MS-Off Ver
    Excel 2007
    Posts
    114

    Re: Optimizing excel formula

    this is an example of what i have. Sheet 2 represents quantities of parts that i purchased, sheet 3 represents the price per meter of one part. behind those cells usually are formulas that get the price from another sheet, prices that can change each month from different supliers, different quantities and so on, but that is not important for our situation here. And on the first sheet we have the "savings". we have the part "506632", month, supliers.

    SumProduct.xlsx

  5. #5
    Forum Expert RobertMika's Avatar
    Join Date
    06-22-2009
    Location
    Haverhill, UK
    MS-Off Ver
    Excel 2003-13
    Posts
    1,530

    Re: Optimizing excel formula

    Can you put your desired result into workbook?

  6. #6
    Forum Contributor
    Join Date
    07-22-2013
    Location
    Sibiu
    MS-Off Ver
    Excel 2007
    Posts
    114

    Re: Optimizing excel formula

    The standard price is set by the board, so the reference is the quantity of 506632 * standard price and savings being of course the diference beetween reference and all the others. if + we saved money if - we lost.
    SumProduct.xlsx

  7. #7
    Forum Expert RobertMika's Avatar
    Join Date
    06-22-2009
    Location
    Haverhill, UK
    MS-Off Ver
    Excel 2003-13
    Posts
    1,530

    Re: Optimizing excel formula

    If this help a bit:
    =IFERROR(SUMIFS(Sheet2!$F$7:$F$13,Sheet2!$C$7:$C$13,$I$34,Sheet2!$G$7:$G$13,J$34)*INDEX(Sheet3!$C$10:$O$26,MATCH($I$34&$I35,Sheet3!$C$10:$C$26&Sheet3!$E$10:$E$26,0),MATCH(J34,Sheet3!C$11:O$11,0)),0)

    Confirm COntrl+Shift+Enter

  8. #8
    Forum Contributor
    Join Date
    07-22-2013
    Location
    Sibiu
    MS-Off Ver
    Excel 2007
    Posts
    114

    Re: Optimizing excel formula

    I will have to check to see how much time it will save me, but i doubt it will make a huge difference because it's still an array formula but thank you very much for the help.

  9. #9
    Forum Expert RobertMika's Avatar
    Join Date
    06-22-2009
    Location
    Haverhill, UK
    MS-Off Ver
    Excel 2003-13
    Posts
    1,530

    Re: Optimizing excel formula

    The second INDEX can be converted to non-array formula but this does not mean it will be faster in calculation.
    Not all arrays are slower than the "normal" one.

  10. #10
    Forum Expert bebo021999's Avatar
    Join Date
    07-22-2011
    Location
    Vietnam
    MS-Off Ver
    Excel 2016
    Posts
    9,466

    Re: Optimizing excel formula

    In sheet 3 there are many minus signs "-" as text. To increase the calculation, use SUMPRODUCT for 2nd part, try to replace minus signs "-" with 0 or blank, then apply below formula:
    Please Login or Register  to view this content.
    Attached Files Attached Files
    Quang PT

+ 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. Optimizing Portfolio in Excel
    By NFS in forum Excel Formulas & Functions
    Replies: 1
    Last Post: 11-08-2012, 01:22 PM
  2. optimizing any bottle neck in an excel workbook
    By thosecars82 in forum Excel General
    Replies: 2
    Last Post: 04-18-2012, 11:50 AM
  3. Optimizing my formula
    By Lurr in forum Excel General
    Replies: 7
    Last Post: 06-21-2011, 03:32 PM
  4. Optimizing Excel macro to find/replace with the list of data contained in the macro
    By Iceyburnz in forum Excel Programming / VBA / Macros
    Replies: 5
    Last Post: 12-17-2008, 08:41 PM
  5. Optimizing formula?
    By jkenney111 in forum Excel General
    Replies: 5
    Last Post: 12-20-2006, 06:44 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