Microsoft Office Forums

Go Back   Microsoft Office Forums > >

Reply
 
Thread Tools Display Modes
  #1  
Old 07-21-2016, 07:31 AM
gebobs gebobs is offline Select value from table based on two criteria Windows 7 64bit Select value from table based on two criteria Office 2010 64bit
Expert
Select value from table based on two criteria
 
Join Date: Mar 2014
Location: Atlanta
Posts: 837
gebobs has a spectacular aura aboutgebobs has a spectacular aura about
Default Select value from table based on two criteria

OK...total brain meltdown here. I need to find the value in the third column of a table based on the values in the first two. It's basically a small lookup table with four unique rows.

So I did this in Google docs using Sumproduct but when I exported it to Excel, something is amiss. I've done it this way before in Excel, but I can't seem to figure out where I've gone wrong.

If someone could lead the way or point me to another solution, I'd appreciate it.



In the attached workbook, the lookup table, Prices, is in the tab named Metrics. There are three columns: Density, Material, and Cost. As you can see, there are just two different densities and materials an, for each combination a unique cost, and thus a total of four rows. The test row I am using (density=14 and material=E) is highlighted.

Highlighted on the first tab, Summary, is the cell with the formula I am having fits with and the other cells in the table that it refers to. Basically, I want it to find the cost in the Prices table using the density and material of the SKU for that row. The formula as is:

=SUMPRODUCT([@Material]=Prices[Material],[@Density]=Prices[Density],Prices[Cost])*[@BF]

So it should return cost for the criteria in that row (density=14 and material=E) and multiply that number by the value for BF (i.e. board feet).

=Cost(14,E)*BF
=0.2968*7906
=2346.50

As you can see, the formula returns a big fat zero. Sorry for the long explanation. I'm sure it's a simple solution for one of you smart folk. Cheers!
Attached Files
File Type: xlsx Price Calculator.xlsx (16.9 KB, 11 views)
Reply With Quote
  #2  
Old 07-21-2016, 08:03 AM
Pecoflyer's Avatar
Pecoflyer Pecoflyer is offline Select value from table based on two criteria Windows 7 64bit Select value from table based on two criteria Office 2010 64bit
Expert
 
Join Date: Nov 2011
Location: Brussels Belgium
Posts: 2,779
Pecoflyer has a brilliant futurePecoflyer has a brilliant futurePecoflyer has a brilliant futurePecoflyer has a brilliant futurePecoflyer has a brilliant futurePecoflyer has a brilliant futurePecoflyer has a brilliant futurePecoflyer has a brilliant futurePecoflyer has a brilliant futurePecoflyer has a brilliant futurePecoflyer has a brilliant future
Default

This seems to work =SUMPRODUCT(--([@Material]=Prices[Material])*([@Density]=Prices[Density])*Prices[Cost])*[@BF]
Don't ask me why the other doesn't
__________________
Did you know you can thank someone who helped you? Click on the tiny scale in the right upper hand corner of your helper's post
Reply With Quote
  #3  
Old 07-21-2016, 08:10 AM
Pecoflyer's Avatar
Pecoflyer Pecoflyer is offline Select value from table based on two criteria Windows 7 64bit Select value from table based on two criteria Office 2010 64bit
Expert
 
Join Date: Nov 2011
Location: Brussels Belgium
Posts: 2,779
Pecoflyer has a brilliant futurePecoflyer has a brilliant futurePecoflyer has a brilliant futurePecoflyer has a brilliant futurePecoflyer has a brilliant futurePecoflyer has a brilliant futurePecoflyer has a brilliant futurePecoflyer has a brilliant futurePecoflyer has a brilliant futurePecoflyer has a brilliant futurePecoflyer has a brilliant future
Default

I suspect the comma does not coerce TRUE/FALSE to 1/0 where the * operator does
__________________
Did you know you can thank someone who helped you? Click on the tiny scale in the right upper hand corner of your helper's post
Reply With Quote
  #4  
Old 07-21-2016, 08:19 AM
gebobs gebobs is offline Select value from table based on two criteria Windows 7 64bit Select value from table based on two criteria Office 2010 64bit
Expert
Select value from table based on two criteria
 
Join Date: Mar 2014
Location: Atlanta
Posts: 837
gebobs has a spectacular aura aboutgebobs has a spectacular aura about
Default

Ahhhh...I'm forever switching between the two and never knew why any particular combination worked and another didn't.

Good karma for you, mate! Thanks!
Reply With Quote
  #5  
Old 07-21-2016, 08:26 AM
Pecoflyer's Avatar
Pecoflyer Pecoflyer is offline Select value from table based on two criteria Windows 7 64bit Select value from table based on two criteria Office 2010 64bit
Expert
 
Join Date: Nov 2011
Location: Brussels Belgium
Posts: 2,779
Pecoflyer has a brilliant futurePecoflyer has a brilliant futurePecoflyer has a brilliant futurePecoflyer has a brilliant futurePecoflyer has a brilliant futurePecoflyer has a brilliant futurePecoflyer has a brilliant futurePecoflyer has a brilliant futurePecoflyer has a brilliant futurePecoflyer has a brilliant futurePecoflyer has a brilliant future
Default

Perhaps this link can shed some light

The basic idea is that arithmetic operators automatically coerce
__________________
Did you know you can thank someone who helped you? Click on the tiny scale in the right upper hand corner of your helper's post
Reply With Quote
Reply



Similar Threads
Thread Thread Starter Forum Replies Last Post
Select value from table based on two criteria Selecting random cells based on criteria mesTrethowan Excel 11 10-28-2015 06:51 AM
Select value from table based on two criteria Complex Mail Merge based on Criteria fairchance Mail Merge 11 08-22-2015 04:32 AM
transpose values based on mulitple criteria mlttkw Excel 1 12-06-2013 02:00 AM
MACRO - Insert row based on Form Field Criteria Elan05 Word VBA 5 04-16-2013 06:39 AM
Change values in cells based on criteria SaneMan Excel Programming 2 02-02-2012 07:58 AM

Other Forums: Access Forums

All times are GMT -7. The time now is 02:06 PM.


Powered by vBulletin® Version 3.8.11
Copyright ©2000 - 2024, vBulletin Solutions Inc.
Search Engine Optimisation provided by DragonByte SEO (Lite) - vBulletin Mods & Addons Copyright © 2024 DragonByte Technologies Ltd.
MSOfficeForums.com is not affiliated with Microsoft