Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase 12»»

Query to find cheapest supplier when multiple suppliers? Expand / Collapse
Author
Message
Posted Thursday, March 14, 2013 1:38 PM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Wednesday, July 30, 2014 2:01 PM
Points: 8, Visits: 31
Hi I have the following table (created from a view):

BaseSupplierID__SupplierID___ProductID__Price
3_______________3___________1________11
3_______________4___________1________11
3_______________5___________1________15
3_______________6___________1________10

4_______________3___________2________16
4_______________4___________2________10

5_______________5___________3________16
5_______________8___________3________14
5_______________9___________3________10

Basically each product can be supplied from multiple supplies yet there is a base supplier (which in theory should be the cheapest). I need to create a query that would show me the products where the base supplier was not the cheapest for their products? Any pointers?? Thanks
Post #1431227
Posted Thursday, March 14, 2013 1:43 PM


SSChampion

SSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampion

Group: General Forum Members
Last Login: Today @ 8:07 PM
Points: 12,910, Visits: 32,028
r-276086 (3/14/2013)
Hi I have the following table (created from a view):

BaseSupplierID__SupplierID___ProductID__Price
3_______________3___________1________11
3_______________4___________1________11
3_______________5___________1________15
3_______________6___________1________10

4_______________3___________2________16
4_______________4___________2________10

5_______________5___________3________16
5_______________8___________3________14
5_______________9___________3________10

Basically each product can be supplied from multiple supplies yet there is a base supplier (which in theory should be the cheapest). I need to create a query that would show me the products where the base supplier was not the cheapest for their products? Any pointers?? Thanks

seems like a homework question, so I'll try and help you learn, instead of spoon feeding an answer;

the idea here is to use the MIN() and MAX() functions and a GROUP BY clause.
in this case, since you are looking for the cheapest supplier for a specific product;

an alternative is to use the ROW_NUMBER() OVER(PARTITION BY .. ORDER BY..) to order the data, and look at the min or max values that way as well.

let us see what you've tried so far so we can help you understand the concepts.

If you can supply the CREATE TABLE... and INSERT INTO commands, we can give you working examples or edits of your code to help you better.
something like this is what i mean:
With MySampleData (BaseSupplierID,SupplierID,ProductID,Price)
AS
(
SELECT 3,3,1,11 UNION ALL
SELECT 3,4,1,11 UNION ALL
SELECT 3,5,1,15 UNION ALL
SELECT 3,6,1,10 UNION ALL
SELECT 4,3,2,16 UNION ALL
SELECT 4,4,2,10 UNION ALL
SELECT 5,5,3,16 UNION ALL
SELECT 5,8,3,14 UNION ALL
SELECT 5,9,3,10
)

select * from MySampleData



Lowell

--There is no spoon, and there's no default ORDER BY in sql server either.
Actually, Common Sense is so rare, it should be considered a Superpower. --my son
Post #1431228
Posted Thursday, March 14, 2013 2:02 PM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Wednesday, July 30, 2014 2:01 PM
Points: 8, Visits: 31
Hi, thanks for the quick response. Its not a homework question (I'm 30+ ) and I've been lumbered with this from work.

This is some create/insert code:
CREATE TABLE [dbo].[test1](
[BaseSupplierID] [int] NOT NULL,
[SupplierID] [int] NOT NULL,
[ProductID] [int] NOT NULL,
[Price] [money] NOT NULL
) ON [PRIMARY]
GO
INSERT [dbo].[test1] ([BaseSupplierID], [SupplierID], [ProductID], [Price]) VALUES (3, 3, 1, 11.0000)
INSERT [dbo].[test1] ([BaseSupplierID], [SupplierID], [ProductID], [Price]) VALUES (3, 4, 1, 11.3400)
INSERT [dbo].[test1] ([BaseSupplierID], [SupplierID], [ProductID], [Price]) VALUES (3, 5, 1, 15.0000)
INSERT [dbo].[test1] ([BaseSupplierID], [SupplierID], [ProductID], [Price]) VALUES (3, 5, 1, 10.0000)
INSERT [dbo].[test1] ([BaseSupplierID], [SupplierID], [ProductID], [Price]) VALUES (4, 3, 2, 16.0000)
INSERT [dbo].[test1] ([BaseSupplierID], [SupplierID], [ProductID], [Price]) VALUES (4, 4, 2, 10.0000)
INSERT [dbo].[test1] ([BaseSupplierID], [SupplierID], [ProductID], [Price]) VALUES (5, 5, 3, 16.0000)
INSERT [dbo].[test1] ([BaseSupplierID], [SupplierID], [ProductID], [Price]) VALUES (5, 8, 3, 14.0000)
INSERT [dbo].[test1] ([BaseSupplierID], [SupplierID], [ProductID], [Price]) VALUES (5, 9, 3, 10.0000)

I'm thinking I have to use Min() in a sub query? I think I have the sub query part of what I need

SELECT   MIN(Price) as Cheapest, ProductID, SupplierID, BaseSupplierID 
FROM test1
GROUP By ProductID, SupplierID, BaseSupplierID

but not sure how to use it?
Thanks
Post #1431248
Posted Thursday, March 14, 2013 2:15 PM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Wednesday, July 30, 2014 2:01 PM
Points: 8, Visits: 31
think I may have something
SELECT co1.productID, co1.supplierID, co1.price, co1.basesupplierID
FROM test1 AS co1,
(SELECT productID, MIN(price) AS minPrice
FROM test1
GROUP BY productID) AS co2
WHERE co2.productID = co1.productID
and co1.price = co2.minPrice;

Can you suggest any improvements?
Post #1431255
Posted Thursday, March 14, 2013 2:17 PM


SSChampion

SSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampion

Group: General Forum Members
Last Login: Today @ 8:07 PM
Points: 12,910, Visits: 32,028
ok great!
the trick here is you really need two queries, adn compare them agaisnt each otehr;
you already have the cheapest supplier, but now you wnat to know which regular supplier might be cheaper than teh base supplier.
first, lets get the base supplier's prices:
/*
--results
Cheapest ProductID SupplierID BaseSupplierID
--------------------- ----------- ----------- --------------
11.00 1 3 3
10.00 2 4 4
16.00 3 5 5
*/
SELECT MIN(Price) as BasePrice, ProductID, SupplierID, BaseSupplierID
FROM test1
WHERE SupplierID= BaseSupplierID --where the supplier is the base supplier
GROUP By ProductID, SupplierID, BaseSupplierID

now using either a set of subqueries or CTE's, lets compare those two result sets: the results are identical, but CTE's are maybe a little easier to read.

--as subqueries:

SELECT * FROM(
SELECT MIN(Price) as Cheapest, ProductID, SupplierID, BaseSupplierID
FROM test1
GROUP By ProductID, SupplierID, BaseSupplierID
) TheCheapest
LEFT OUTER JOIN
(
SELECT MIN(Price) as BasePrice, ProductID, SupplierID, BaseSupplierID
FROM test1
WHERE SupplierID= BaseSupplierID
GROUP By ProductID, SupplierID, BaseSupplierID
) BaseSupplierPrices
ON TheCheapest.ProductID = BaseSupplierPrices.ProductID
WHERE TheCheapest.Cheapest < BaseSupplierPrices.BasePrice

As CTE's
With TheCheapest
AS
(

SELECT MIN(Price) as Cheapest, ProductID, SupplierID, BaseSupplierID
FROM test1
GROUP By ProductID, SupplierID, BaseSupplierID
) , BaseSupplierPrices
AS
(
SELECT MIN(Price) as BasePrice, ProductID, SupplierID, BaseSupplierID
FROM test1
WHERE SupplierID= BaseSupplierID
GROUP By ProductID, SupplierID, BaseSupplierID
)

SELECT *
FROM TheCheapest
LEFT OUTER JOIN BaseSupplierPrices
ON TheCheapest.ProductID = BaseSupplierPrices.ProductID
WHERE TheCheapest.Cheapest < BaseSupplierPrices.BasePrice



Lowell

--There is no spoon, and there's no default ORDER BY in sql server either.
Actually, Common Sense is so rare, it should be considered a Superpower. --my son
Post #1431257
Posted Thursday, March 14, 2013 3:34 PM
SSCrazy

SSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazy

Group: General Forum Members
Last Login: Today @ 1:49 PM
Points: 2,044, Visits: 3,062
Poor HAVING, nobody likes him

SELECT
ProductID, BaseSupplierID,
MIN(CASE WHEN SupplierID <> BaseSupplierID THEN Price END) AS LowestPrice,
MIN(CASE WHEN SupplierID = BaseSupplierID THEN Price END) AS BaseSupplierPrice
FROM dbo.test1
GROUP BY
ProductID, BaseSupplierID
HAVING
MIN(CASE WHEN SupplierID <> BaseSupplierID THEN Price END) <
MIN(CASE WHEN SupplierID = BaseSupplierID THEN Price END)



SQL DBA,SQL Server MVP('07, '08, '09)
"In America, every man is innocent until proven broke!" Brant Parker
Post #1431280
Posted Thursday, March 14, 2013 7:43 PM


SSC-Dedicated

SSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-Dedicated

Group: General Forum Members
Last Login: Today @ 10:19 PM
Points: 36,995, Visits: 31,523
Sorry... made a mistake on the requirements. Post withdrawn.

--Jeff Moden
"RBAR is pronounced "ree-bar" and is a "Modenism" for "Row-By-Agonizing-Row".

First step towards the paradigm shift of writing Set Based code:
Stop thinking about what you want to do to a row... think, instead, of what you want to do to a column."

(play on words) "Just because you CAN do something in T-SQL, doesn't mean you SHOULDN'T." --22 Aug 2013

Helpful Links:
How to post code problems
How to post performance problems
Post #1431323
Posted Thursday, March 14, 2013 7:50 PM


SSC-Dedicated

SSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-Dedicated

Group: General Forum Members
Last Login: Today @ 10:19 PM
Points: 36,995, Visits: 31,523
ScottPletcher (3/14/2013)
Poor HAVING, nobody likes him

SELECT
ProductID, BaseSupplierID,
MIN(CASE WHEN SupplierID <> BaseSupplierID THEN Price END) AS LowestPrice,
MIN(CASE WHEN SupplierID = BaseSupplierID THEN Price END) AS BaseSupplierPrice
FROM dbo.test1
GROUP BY
ProductID, BaseSupplierID
HAVING
MIN(CASE WHEN SupplierID <> BaseSupplierID THEN Price END) <
MIN(CASE WHEN SupplierID = BaseSupplierID THEN Price END)



Nicely done, Scott. The only thing is that there'd have to be another query to show the SupplierID that came in the lowest.


--Jeff Moden
"RBAR is pronounced "ree-bar" and is a "Modenism" for "Row-By-Agonizing-Row".

First step towards the paradigm shift of writing Set Based code:
Stop thinking about what you want to do to a row... think, instead, of what you want to do to a column."

(play on words) "Just because you CAN do something in T-SQL, doesn't mean you SHOULDN'T." --22 Aug 2013

Helpful Links:
How to post code problems
How to post performance problems
Post #1431326
Posted Thursday, March 14, 2013 8:23 PM


SSC-Dedicated

SSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-Dedicated

Group: General Forum Members
Last Login: Today @ 10:19 PM
Points: 36,995, Visits: 31,523
Lowell (3/14/2013)
With TheCheapest
AS
(
SELECT MIN(Price) as Cheapest, ProductID, SupplierID, BaseSupplierID
FROM test1
GROUP By ProductID, SupplierID, BaseSupplierID
) ,
BaseSupplierPrices AS
(
SELECT MIN(Price) as BasePrice, ProductID, SupplierID, BaseSupplierID
FROM test1
WHERE SupplierID= BaseSupplierID
GROUP By ProductID, SupplierID, BaseSupplierID
)
SELECT *
FROM TheCheapest
LEFT OUTER JOIN BaseSupplierPrices
ON TheCheapest.ProductID = BaseSupplierPrices.ProductID
WHERE TheCheapest.Cheapest < BaseSupplierPrices.BasePrice



That's the way I probably would have done it because it shows all of the suppliers with a lower price than the base. It will give the "decision maker" the option to pick a supplier and that's important because a supplier with the lowest price might be on some black list or in another country were lead time might become a problem.

It also shows what the current price is so that if both less expensive suppliers are in another country or there are other mitigating circumstances (like shipping costs), the decision maker can do the comparison and decide if it's actually worth it.


--Jeff Moden
"RBAR is pronounced "ree-bar" and is a "Modenism" for "Row-By-Agonizing-Row".

First step towards the paradigm shift of writing Set Based code:
Stop thinking about what you want to do to a row... think, instead, of what you want to do to a column."

(play on words) "Just because you CAN do something in T-SQL, doesn't mean you SHOULDN'T." --22 Aug 2013

Helpful Links:
How to post code problems
How to post performance problems
Post #1431334
Posted Thursday, March 14, 2013 8:43 PM


SSC-Dedicated

SSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-Dedicated

Group: General Forum Members
Last Login: Today @ 10:19 PM
Points: 36,995, Visits: 31,523
Here's a different take on it. The absence of aggregates makes it pretty easy to manipulate the output just about any way that you'd like and you'll never have to worry about a NULL aggregate message.

WITH
cteBase AS
(
SELECT BaseSupplierID, SupplierID, ProductID, Price
FROM dbo.Test1
WHERE BaseSupplierID = SupplierID
)
SELECT b.ProductID,
b.BaseSupplierID,
CurrentPrice = b.Price,
LowerPrice = t1.Price,
Savings = b.Price-t1.Price,
AlternateSupplierID = t1.SupplierID
FROM dbo.Test1 t1
JOIN cteBase b
ON t1.BaseSupplierID = b.BaseSupplierID
AND t1.ProductID = b.ProductID
AND t1.Price < b.Price
ORDER BY b.ProductID,
b.BaseSupplierID,
Savings DESC
;

Using the OP's readily consumable data, here's what the output looks like.

ProductID BaseSupplierID CurrentPrice LowerPrice Savings AlternateSupplierID
--------- -------------- ------------ ---------- ------- -------------------
1 3 11.00 10.00 1.00 5
3 5 16.00 10.00 6.00 9
3 5 16.00 14.00 2.00 8

(3 row(s) affected)


--Jeff Moden
"RBAR is pronounced "ree-bar" and is a "Modenism" for "Row-By-Agonizing-Row".

First step towards the paradigm shift of writing Set Based code:
Stop thinking about what you want to do to a row... think, instead, of what you want to do to a column."

(play on words) "Just because you CAN do something in T-SQL, doesn't mean you SHOULDN'T." --22 Aug 2013

Helpful Links:
How to post code problems
How to post performance problems
Post #1431338
« Prev Topic | Next Topic »

Add to briefcase 12»»

Permissions Expand / Collapse