关于SQLServer2005的学习笔记——SQL查询解析步骤
最近一来因工作上的事情比较闹心,没心事再研究 SQLServer2005 的体系结构;一来关于体系结构确实过于复杂,远远不如应用来的直接明了,所以暂时搁笔。 出于工作上的需要,对应用开发需要更多的了解,所以把心事暂时放到这方面。 ? 先从最简单的 SQL 入手来分析一下 SQL 的执行步骤,为什么了解执行步骤,其实与 JOIN 后的 ON 条件和 WHERE 条件容易混淆有关系。 是先执行 ON 还是先执行 WHERE ,很大程度上会决定 SQL 的结果集正确与否。 CREATE TABLE Customers ( ? CustomerID? CHAR(5)???? NOT NULL PRIMARY KEY, ? City??????? VARCHAR(10) NOT NULL ); CREATE TABLE Orders ( ? OrderID???? INT???? NOT NULL PRIMARY KEY, ? CustomerID? CHAR(5) NULL REFERENCES Customers(CustomerID) ); ? INSERT INTO Customers VALUES('FISSA','Madrid'); INSERT INTO Customers VALUES('FRNDO','Madrid'); INSERT INTO Customers VALUES('KRLOS','Madrid'); INSERT INTO Customers VALUES('MRPHS','Zion'); INSERT INTO Orders VALUES(1,'FRNDO'); INSERT INTO Orders VALUES(2,'FRNDO'); INSERT INTO Orders VALUES(3,'KRLOS'); INSERT INTO Orders VALUES(4,'KRLOS'); INSERT INTO Orders VALUES(5,'KRLOS'); INSERT INTO Orders VALUES(6,'MRPHS'); INSERT INTO Orders VALUES(7,NULL); ? 试看看以上两个语句有什么不同,你就会发现很有趣的现象。 SELECT C.CustomerID,COUNT(O.OrderID) AS NumOrders ? FROM Customers C ? LEFT OUTER JOIN Orders O ??? ON C.CustomerID=O.CustomerID ? WHERE C.City='Madrid' ? GROUP BY C.CustomerID ? HAVING COUNT(O.OrderID)<3 ? ORDER BY NumOrders; ? SELECT C.CustomerID,COUNT(O.OrderID) AS NumOrders ? FROM Customers C ? LEFT OUTER JOIN Orders O ??? ON C.CustomerID=O.CustomerID ??? AND C.City='Madrid' ? GROUP BY C.CustomerID ? HAVING COUNT(O.OrderID)<3 ? ORDER BY NumOrders; ? --Step1 ,首先对 FROM 后面的表进行笛卡尔乘积,生成虚表 STEP1 WITH STEP1 AS ( SELECT C.CustomerID C_CustomerID,C.City C_City,O.OrderID O_OrderID,O.CustomerID O_CustomerID ? FROM Customers C,Orders O ) SELECT * FROM STEP1 ? --Step2 ,再次应用 ON 语句中的条件,如果没有外关联的话,这里的 ON 和 WHERE 实际上是没有什么差别的,生成虚表 STEP2 WITH STEP2 AS ( SELECT C.CustomerID C_CustomerID,O.CustomerID O_CustomerID ? FROM Customers C ? JOIN Orders O ??? ON C.CustomerID=O.CustomerID ) SELECT * FROM STEP2 ? --Step3 ,如果指定了 OUTER JOIN , SQL 会自动把 STEP2 表中未匹配的行作为外部行添加到 STEP3 中,此处找到了 CustomerID=FISSA,City=Madrid ,这个没有订单但又有相关名字的用户 WITH STEP3 AS ( SELECT C.CustomerID C_CustomerID,O.CustomerID O_CustomerID ? FROM Customers C ? LEFT OUTER JOIN Orders O ??? ON C.CustomerID=O.CustomerID ) SELECT * FROM STEP3 ? --Step4 ,应用 WHERE 条件,过滤不符合条件的记录 AS ( SELECT C.CustomerID C_CustomerID,O.CustomerID O_CustomerID ? FROM Customers C ? LEFT OUTER JOIN Orders O ??? ON C.CustomerID=O.CustomerID ? WHERE C.City='Madrid' ) SELECT * FROM STEP4 ? --Step5 ,对以上的结果集进行分组 WITH STEP5 AS ( SELECT C.CustomerID,COUNT(O.OrderID) AS NumOrders ? FROM Customers C ? LEFT OUTER JOIN Orders O ??? ON C.CustomerID=O.CustomerID ? WHERE C.City='Madrid' ? GROUP BY C.CustomerID ) SELECT * FROM STEP5 ? --Step6 ,处理 CUBE 、 ROLLUP 之类的语句,此处无此需求 略 SELECT * FROM STEP6 ? --Step7 处理 Having 筛选器,与 WHERE 条件有些类似 WITH STEP7 AS ( SELECT C.CustomerID,COUNT(O.OrderID) AS NumOrders ? FROM Customers C ? LEFT OUTER JOIN Orders O ??? ON C.CustomerID=O.CustomerID ? WHERE C.City='Madrid' ? GROUP BY C.CustomerID ? HAVING COUNT(O.OrderID)<3 ) SELECT * FROM STEP7 ? --Step8 ,处理 SELECT 列表,即别名转换把 COUNT(O.OrderID) 转换成 NumOrders 略 SELECT * FROM STEP8 ? --Step9 ,应用 DISTINCT 语句,此处无此需求 略 SELECT * FROM STEP9 ? --Step10 ,应用 ORDER BY 语句进行排序 SELECT C.CustomerID,COUNT(O.OrderID) AS NumOrders ? FROM Customers C ? LEFT OUTER JOIN Orders O ??? ON C.CustomerID=O.CustomerID ? WHERE C.City='Madrid' ? GROUP BY C.CustomerID ? HAVING COUNT(O.OrderID)<3 ? ORDER BY NumOrders ? --Step11 ,执行 TOP 选项,此处无此需求 略 SELECT * FROM STEP11
(编辑:李大同) 【声明】本站内容均来自网络,其相关言论仅代表作者个人观点,不代表本站立场。若无意侵犯到您的权利,请及时与联系站长删除相关内容! |