+ Reply to Thread
Results 1 to 4 of 4

Finding lowest cost carrier among an arry.

  1. #1
    Registered User
    Join Date
    05-15-2015
    Location
    United States
    MS-Off Ver
    2013
    Posts
    67

    Finding lowest cost carrier among an arry.

    Hello -

    I have a spread sheet that has multiple carriers, metallics and rates. I'm looking to find the lowest carrier among bronze rates.

    See attached.
    Attached Files Attached Files

  2. #2
    Forum Expert Logit's Avatar
    Join Date
    12-23-2012
    Location
    North Carolina
    MS-Off Ver
    Excel 2019 Professional Plus - 2007 Enterprise
    Posts
    7,014

    Re: Finding lowest cost carrier among an arry.

    .

    Here is one way :


    Paste in L3 and drag down to L7 :
    Please Login or Register  to view this content.
    Paste in L9 :
    Please Login or Register  to view this content.

  3. #3
    Valued Forum Contributor
    Join Date
    05-11-2013
    Location
    Wales
    MS-Off Ver
    Excel 2010
    Posts
    586

    Re: Finding lowest cost carrier among an arry.

    Hi kcgojnur,

    Another way:-

    Select and copy all Data
    Paste Special and Transpose
    Add Filter to top Row (Materials)
    Click "Bronze" deselect all and select the first value listed (i.e. lowest)
    This will filter the list down to show the lowest price and the name of the carrier

    Regards

    peterrc

  4. #4
    Forum Moderator Glenn Kennedy's Avatar
    Join Date
    07-08-2012
    Location
    Digital Nomad... occasionally based in Ireland.
    MS-Off Ver
    O365 (PC) V 2403
    Posts
    44,052

    Re: Finding lowest cost carrier among an arry.

    Hi. Ties results sometimes make a mess of "simpler" formulae

    This array formula to return the minimum cost:
    =MIN(IF($A$3:$A$7="Bronze",$B$3:$K$7))

    and this array formula to return the cheapest provider:
    =INDEX($B$2:$K$2,SUMPRODUCT(($B$3:$K$7=$B$11)*(COLUMN($B$3:$K$7)-COLUMN($B$3)+1)))
    fall over when tied results are encountered. If this is not possible, fine.

    However, to cover for possible ties in rows and columns, some more elaborate formulae are required. It's made even messier by the fact thta your table contains a mix of numbers and text.

    To return the cheapest cost, an array formula:
    =MIN(IFERROR(IF($A$3:$A$7="Bronze",$B$3:$K$7+(COLUMN($B$3:$K$7)/10^10)+ROW(B3:K7)/10^6),10^10))

    but if bronze and bronze plus are BOTH to be considered:
    =MIN(IFERROR(IF(ISNUMBER(SEARCH("Bronze",$A$3:$A$7)),$B$3:$K$7+(COLUMN($B$3:$K$7)/10^10+ROW(B3:K7)/10^6)),10^10))

    and to return the cheapest carrier:
    =INDEX($B$2:$K$2,SUMPRODUCT((IFERROR($B$3:$K$7+(COLUMN($B$3:$K$7)/10^10+ROW(B3:K7)/10^6),10^4)=$F$11)*(COLUMN($B$3:$K$7)-COLUMN($B$3)+1)))


    All are array formulae.


    Array Formulae are a little different from ordinary formulae in that they MUST be confirmed in the FIRST CELL ONLY by pressing CTRL+SHIFT+ENTER to activate the array, not just ENTER. After that, the array can be dragged down as normal, to cover the desired range.

    You will know the array is active when you see curly brackets { } - or "curly braces" for those of you in the USA, or "flower brackets" for those of you in India - appear around the outside of your formula. If you do not use CTRL+SHIFT+ENTER you will (almost always) get an error message or an incorrect answer. Press F2 on that cell and try again.

    Don't type the curly brackets yourself - it won't work...
    Attached Files Attached Files
    Glenn




    None of us get paid for helping you... we do this for fun. So DON'T FORGET to say "Thank You" to all who have freely given some of their time to help YOU.

    Temporary addition of accented to illustrate ongoing problem to the TT: L? fh?ile P?draig sona dhaoibh

+ 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] Finding the lowest carrier amoung a specific list
    By kcgojnur in forum Excel Formulas & Functions
    Replies: 6
    Last Post: 08-22-2017, 10:54 AM
  2. Lowest Cost Vendor
    By rafilip in forum Excel Programming / VBA / Macros
    Replies: 1
    Last Post: 06-25-2012, 01:59 PM
  3. Lowest Cost Vendor
    By rafilip in forum Excel General
    Replies: 0
    Last Post: 06-25-2012, 01:31 PM
  4. Finding Lowest Cost from a List with Wildcard
    By 123Steve in forum Excel General
    Replies: 11
    Last Post: 11-15-2011, 12:16 AM
  5. finding lowest cost from supplier list
    By jimbokeep in forum Excel General
    Replies: 4
    Last Post: 08-05-2010, 06:03 AM
  6. Finding lowest cost price with multiple criteria
    By jimbokeep in forum Excel General
    Replies: 8
    Last Post: 06-30-2010, 01:11 PM
  7. Finding Lowest Cost/Vendor
    By nadiaz in forum Excel General
    Replies: 2
    Last Post: 10-24-2007, 11:20 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