September 8, 2010 at 7:51 am
Robert Frasca (9/8/2010)
..., there can never be anything GREATER THAN a?...
Robert, I believe the key is to treat the groups individually. Therefore, when Group 1 from "a" is being evaluated (because of the group by), it is being evaluated against the whole QotD table "b".
Here, we are looking for the GroupNames from the grouped set "a" whose MAX(a.TheValue) values are less than the "b.TheValue"
Since the MAX(a.TheValue) for Group 1 is 3, which is same as the max value for "b" it does not appear in the result set.
The MAX(a.TheValue) for Group 2 is 2, which is less than "b", and therefore it appears in the result set.
Hope that clears things out a bit. You can break the query into two, with the first part being:
SELECT a.GroupName, MAX(a.TheValue)
FROM QotD AS a
GROUP BY a.GroupName, a.TheValue
Now compare this with "b" - you should start getting a feel of the internal workings.
Thanks & Regards,
Nakul Vachhrajani.
http://nakulvachhrajani.com
Follow me on
Twitter: @sqltwins
September 8, 2010 at 8:36 am
In a recent blog, Kalen Delaney said she is frequently asked why is there a need to understand the internals of SQL Server. I think this question illustrates why. The key to getting the right answer is an understanding of the sequence of events during the query processing - the HAVING clause is processed after the GROUP BY and acts on the result set from the earlier phases.
I learned this from Itzik Ben-Gan's book 'Inside Microsoft SQL Server 2008: T-SQL Querying'. Chapter 1, Logical Query Processing, has a great section on the sequence of events that occurs when the query processor gets to work. I really recommend this book to anyone who is struggling to understand the explanation for this QotD.
Tony
September 8, 2010 at 8:37 am
Group 1 - max(a) is 3 ---- nothing in b is greater than a
Group 2 - max(a) is 2 ---- 3 (in b which is the whole table) is greater than 2 so this is true
Group 3 - max(a) is 3 ---- nothing in b is greater than a
Group 4 - max(a) is 3 ---- nothing in b is greater than a
Group 5 - max(a) is 1 ---- 2 & 3 (in b which is the whole table) are greater than 1 so this is true
Group 6 - max(a) is 2 ---- 3 (in b which is the whole table) is greater than 2 so this is true
Group 7 - max(a) is 3 ---- nothing in b is greater than a
Okay, I've got it now. I think I was getting my a and b contexts confused. Thanks for the help folks. It probably helped that I increased my blood caffeine level.
GREAT question. The amount of smoke coming out of my ears has doubled.
"Beliefs" get in the way of learning.
September 8, 2010 at 8:45 am
A while back, I promised to post the QotD code in a copy/paste ready format in the discussion when I have the code as a graphic in the question. Yet, I always forget to do as I promised. My apologies to all those who already spent time typing it in for yourself.
And to those who want to try it out, and experiment to see how small changes affect the result, here is some SQL you can copy and paste:
CREATE TABLE QotD
(GroupName varchar(20) NOT NULL,
TheValue int NOT NULL,
PRIMARY KEY (GroupName, TheValue)
);
go
INSERT INTO QotD (GroupName, TheValue)
SELECT 'Group 1', 1 UNION ALL
SELECT 'Group 1', 2 UNION ALL
SELECT 'Group 1', 3 UNION ALL
SELECT 'Group 2', 1 UNION ALL
SELECT 'Group 2', 2 UNION ALL
SELECT 'Group 3', 1 UNION ALL
SELECT 'Group 3', 3 UNION ALL
SELECT 'Group 4', 2 UNION ALL
SELECT 'Group 4', 3 UNION ALL
SELECT 'Group 5', 1 UNION ALL
SELECT 'Group 6', 2 UNION ALL
SELECT 'Group 7', 3;
go
SELECT a.GroupName --, MAX(a.TheValue)
FROM QotD AS a
GROUP BY a.GroupName
HAVING EXISTS (SELECT *
FROM QotD AS b
WHERE b.TheValue > MAX(a.TheValue));
go
DROP TABLE QotD;
go
EDIT: I added an extra column, commented out, to the SELECT. This might help you see what happens.
September 8, 2010 at 8:46 am
Thanks for the question Hugo and the practical application example. Your explanation of the QOTD from two days ago provided a great refresher and helped me get it right.
In regards to your practice application example, assuming I understand the requirement, I believe there is a mistake in the having clause. See the comment in the first select statement.
Here is a full working example with set up and tear down.
CREATE TABLE Orders(OrderNo INT,OrderDate DATETIME,CustomerNo INT)
CREATE TABLE OrderItems(OrderNo INT,Amount INT, ItemCode VARCHAR(10))
INSERT Orders
VALUES(100,'9-8-10',1),(101,'9-8-10',2),(102,'9-8-10',3)
INSERT OrderItems
VALUES(100,1,'Bike'),(100,2,'Tire'),(101,2,'Spokes'),(102,3,'Pedal')
DECLARE @CustomerNo AS INT = 1
SELECT o.OrderNo, o.OrderDate,
SUM(oi.Amount) AS TotalOrderAmount
FROM Orders AS o
INNER JOIN OrderItems AS oi
ON oi.OrderNo = o.OrderNo
WHERE o.CustomerNo = @CustomerNo
GROUP BY o.OrderNo, o.OrderDate
HAVING NOT EXISTS
(SELECT *
FROM Orders AS o2
INNER JOIN OrderItems AS oi2
ON oi2.OrderNo = o2.OrderNo
WHERE o2.OrderNo <> o.OrderNo
AND o2.OrderDate = o.OrderDate
GROUP BY o2.OrderNo
HAVING COUNT(oi2.ItemCode) = COUNT(oi.ItemCode)); -- Changed the <> to =
SELECT o.OrderNo, o.OrderDate,
SUM(oi.Amount) AS TotalOrderAmount
FROM Orders AS o
INNER JOIN OrderItems AS oi
ON oi.OrderNo = o.OrderNo
WHERE o.CustomerNo = @CustomerNo
GROUP BY o.OrderNo, o.OrderDate
HAVING COUNT(oi.ItemCode) <> ALL
(SELECT COUNT(oi2.ItemCode)
FROM Orders AS o2
INNER JOIN OrderItems AS oi2
ON oi2.OrderNo = o2.OrderNo
WHERE o2.OrderNo <> o.OrderNo
AND o2.OrderDate = o.OrderDate
GROUP BY o2.OrderNo);
DROP TABLE Orders
DROP TABLE OrderItems
September 8, 2010 at 8:48 am
Bradley Deem (9/8/2010)
In regards to your practice application example, assuming I understand the requirement, I believe there is a mistake in the having clause. See the comment in the first select statement.
You are absolutely right. Sorry for that mistake, and thanks for posting the corrected script.
September 8, 2010 at 9:20 am
Good question, but there's an error in the explanation of the answer. At the end, it should say "with a maximum for TheValue of less than 3", not "less than 2".
September 8, 2010 at 10:18 am
Tony Bater (9/8/2010)
In a recent blog, Kalen Delaney said she is frequently asked why is there a need to understand the internals of SQL Server. I think this question illustrates why. The key to getting the right answer is an understanding of the sequence of events during the query processing - the HAVING clause is processed after the GROUP BY and acts on the result set from the earlier phases.I learned this from Itzik Ben-Gan's book 'Inside Microsoft SQL Server 2008: T-SQL Querying'. Chapter 1, Logical Query Processing, has a great section on the sequence of events that occurs when the query processor gets to work. I really recommend this book to anyone who is struggling to understand the explanation for this QotD.
Strictly speaking, this is not about the internals of SQL Server, but about the logical stucture of T-SQL. First and foremost, you need to understand the logical schema, because that's the only way you can write code that fits the schema, as well as tell if a given coding problem is your error or Microsoft's 😛
The primary reason to understand the internals of SQL Server comes after that -- so you can know how to write queries that are not only logically correct, but that will perform well within the constraints of SQL Server and your environment.
In other words, you learn the logical process to write code that works, and then learn the actual internal process so you can write code that works well.
(Disclaimer: I got the question wrong, because I have much to learn about both subjects :hehe: )
September 8, 2010 at 10:25 am
Excellent Question
Jason...AKA CirqueDeSQLeil
_______________________________________________
I have given a name to my pain...MCM SQL Server, MVP
SQL RNNR
Posting Performance Based Questions - Gail Shaw[/url]
Learn Extended Events
September 8, 2010 at 12:42 pm
WOW Hugo. Thanks for the question. Really had me thinking.
September 8, 2010 at 3:07 pm
That made my head swim. I was really confused after the explaination but as usual the discussion cleared it up. Thanks everyone.
September 8, 2010 at 6:02 pm
Great question! Thanks.
September 9, 2010 at 8:51 am
Great question!
September 9, 2010 at 3:23 pm
dbowlin (9/8/2010)
QoTD has really been kicking my butt the last couple of weeks. I had to reread the explanation a couple of times to understand it. Good question, thanks.
Ditto. I'm getting some of them right, but Hugo really has my number. He posts some great questions, and invariably I get them wrong, but in this case I am going to have to study not only his original explanation but also the example he posted in the discussion (above). I don't understand it yet and I really want to.
Thanks, Hugo!
- webrunner
-------------------
A SQL query walks into a bar and sees two tables. He walks up to them and asks, "Can I join you?"
Ref.: http://tkyte.blogspot.com/2009/02/sql-joke.html
September 11, 2010 at 1:53 pm
Really good fun question. Thanks Hugo.
I looked at it for a bit and concluded that if it didn't generate an error message then it should return the three groups with no 3 in them. Would it generate an error? Well, why should it? Having needs a logical condition expression, so an "exists" expression should be OK as long as it obeys the rules for all logical condition expressions in a Having clause (ie don't refer to an non-aggregated column attribute of a row contributing to the group other that one of the grouping attributes). But it took me a while to convince myself that banning "Having Exists" would be silly, in fact I wasn't 100% certain so I was relieved when the website told me I had gotten it correct.
Tom
Viewing 15 posts - 16 through 30 (of 36 total)
You must be logged in to reply to this topic. Login to reply