March 14, 2013 at 1:38 pm
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
March 14, 2013 at 1:43 pm
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
March 14, 2013 at 2:02 pm
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
March 14, 2013 at 2:15 pm
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?
March 14, 2013 at 2:17 pm
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
March 14, 2013 at 3:34 pm
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) "It's a dog-eat-dog world, and I'm wearing Milk-Bone underwear." "Norm", on "Cheers". Also from "Cheers", from "Carla": "You need to know 3 things about Tortelli men: Tortelli men draw women like flies; Tortelli men treat women like flies; Tortelli men's brains are in their flies".
March 14, 2013 at 7:43 pm
Sorry... made a mistake on the requirements. Post withdrawn.
--Jeff Moden
Change is inevitable... Change for the better is not.
March 14, 2013 at 7:50 pm
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
Change is inevitable... Change for the better is not.
March 14, 2013 at 8:23 pm
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
Change is inevitable... Change for the better is not.
March 14, 2013 at 8:43 pm
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
Change is inevitable... Change for the better is not.
March 15, 2013 at 8:22 am
I thought my query might meet the stated requirement while knocking out the second table scan :-).
If OP does need to list the alternate supplier(s), then yes, I think some type of join is required.
SQL DBA,SQL Server MVP(07, 08, 09) "It's a dog-eat-dog world, and I'm wearing Milk-Bone underwear." "Norm", on "Cheers". Also from "Cheers", from "Carla": "You need to know 3 things about Tortelli men: Tortelli men draw women like flies; Tortelli men treat women like flies; Tortelli men's brains are in their flies".
March 15, 2013 at 8:49 am
Fantastic guys thanks for that, plently for me to play with. Suppose I want to track the results over time, what are you thoughts on dumping the results into a table based on a schedule to run the query?
March 16, 2013 at 7:20 pm
ScottPletcher (3/15/2013)
I thought my query might meet the stated requirement while knocking out the second table scan :-).If OP does need to list the alternate supplier(s), then yes, I think some type of join is required.
That's why I said it was nicely done. It does eliminate a scan which, of course, is great for performance.
--Jeff Moden
Change is inevitable... Change for the better is not.
Viewing 13 posts - 1 through 12 (of 12 total)
You must be logged in to reply to this topic. Login to reply
This website stores cookies on your computer.
These cookies are used to improve your website experience and provide more personalized services to you, both on this website and through other media.
To find out more about the cookies we use, see our Privacy Policy