SQL Apprentice Question
What is wrong int this SQL statement? 
select top 10 DOCInt.*, DOCDet.* , Cate.*, Arti.*, [Ar An].* 
from 
DOCInt INNER JOIN DOCDet ON DOCInt.CodDoc=DOCDet.CodDoc 
LEFT JOIN Cate ON DOCDet.IDCategory=Cate.[ID Category] 
LEFT JOIN Arti ON DOCDet.IDArti=Arti.[ID Arti] 
INNER JOIN [Ar An] ON DOCInt.IDAnag=[Ar An].[ID An] 
GROUP BY DOCInt.IDDoc 
Celko Answers
>> What is wrong in this SQL statement? << 
Well, your names are a nightmare that violate common sense and 
ISO-11179 rules, but for now, you do not understand how a SELECT (GROUP 
BY in particular) work: 
Here is how a SELECT works in SQL ... at least in theory.  Real 
products will optimize things, but the code has to produce the same 
results. 
 a) Start in the FROM clause and build a working table from all of the 
joins, unions, intersections, and whatever other table constructors are 
there.  The [table expression] AS [correlation name] option allows you 
give a name to this working table which you then have to use for the 
rest of the containing query. 
 b) Go to the WHERE clause and remove rows that do not pass criteria; 
that is, that do not test to TRUE (i.e. reject UNKNOWN and FALSE).  The 
WHERE clause is applied to the working set in the FROM clause. 
 c) Go to the optional GROUP BY clause, partiton the original table 
into groups and reduce each grouping to a *single* row, replacing the 
original working table with the new grouped table. The rows of a 
grouped table must be only group characteristics: (1) a grouping column 
(2) a statistic about the group (i.e. aggregate functions) (3) a 
function or constant(4) an expression made up of only those three 
items.  The original table no longer exists and you cannot reference 
anything in it (this was an error in early Sybase products). 
 d) Go to the optional HAVING clause and apply it against the grouped 
working table; if there was no GROUP BY clause, treat the entire table 
as one group. 
 e) Go to the SELECT clause and construct the expressions in the list. 
This means that the scalar subqueries, function calls and expressions 
in the SELECT are done after all the other clauses are done.  The AS 
operator can also give names to expressions in the SELECT list.  These 
new names come into existence all at once, but after the WHERE clause, 
GROUP BY clause and HAVING clause have been executed; you cannot use 
them in the SELECT list or the WHERE clause for that reason. 
If there is a SELECT DISTINCT, then redundant duplicate rows are 
removed.  For purposes of defining a duplicate row, NULLs are treated 
as matching (just like in the GROUP BY). 
 f) Nested query expressions follow the usual scoping rules you would 
expect from a block structured language like C, Pascal, Algol, etc. 
Namely, the innermost queries can reference columns and tables in the 
queries in which they are contained. 
 g) The ORDER BY clause is part of a cursor, not a query. The result 
set is passed to the cursor, which can only see the names in the SELECT 
clause list, and the sorting is done there.  The ORDER BY clause cannot 
have expression in it, or references to other columns because the 
result set has been converted into a sequential file structure and that 
is what is being sorted. 
As you can see, things happen "all at once" in SQL, not "from left to 
right" as they would in a sequential file/procedural language model. In 
those languages, these two statements produce different results: 
  READ (a, b, c) FROM File_X; 
  READ (c, a, b) FROM File_X; 
while these two statements return the same data: 
SELECT a, b, c FROM Table_X; 
SELECT c, a, b FROM Table_X; 
Think about what a confused mess this statement is in the SQL model. 
SELECT f(c2) AS c1, f(c1) AS c2 FROM Foobar; 
That is why such nonsense is illegal syntax.
Thursday, November 16, 2006
Subscribe to:
Post Comments (Atom)

 
 
No comments:
Post a Comment