前言
其实有些新的特性在SQL Server早就已经出现过,但是若非系统的去学习数据库你会发现在实际项目中别人的SQL其实是比较复杂的,其实利用新的SQL Server语法会更加方便和简洁,从本节开始我们将讲述一些SQL Server中早已出现的新语法,简短的内容,深入的理解,Always to reivew the basics。
USE TSQL2012
GO
SELECT C.custid, A.orderid, A.orderdate
FROM Sales.Customers AS C
CROSS APPLY
(SELECT TOP(3) orderid, empid, orderdate, requireddate
FROM Sales.Orders AS O
WHERE O.custid = C.custid
ORDER BY orderdate DESC, orderid DESC) AS A;
USE AdventureWorks2012
GO
SELECT
SalesOrderID
,OrderDate
,MaxUnitPrice =(SELECT MAX(sod.UnitPrice) FROM Sales.SalesOrderDetail sod WHERE soh.SalesOrderID = sod.SalesOrderID)
FROM Sales.SalesOrderHeader AS soh
如上操作看似代码比较简洁也能完成我们的查询诉求,但是我们用派生表来进行查询又是怎样的呢?
USE AdventureWorks2012
GO
SELECT
soh.SalesOrderID
,soh.OrderDate
,sod.max_unit_price
FROM Sales.SalesOrderHeader AS soh
JOIN
(
SELECT
max_unit_price = MAX(sod.UnitPrice),
SalesOrderID
FROM Sales.SalesOrderDetail AS sod
GROUP BY sod.SalesOrderID
) sod
ON sod.SalesOrderID = soh.SalesOrderID
此时由于两个表完全不相关,我们需要通过GROUP BY完成再进行JOIN,代码不是显得非常臃肿吗,这还是简单的,当有多个表时就比较复杂了,导致代码就不再具有可读性。但是自从在SQL Server 2005中有了APPLY妈妈再也不用担心我读不懂复杂的代码了,我们看看CROSS APPLY是怎样实现的。
USE AdventureWorks2012
GO
SELECT
soh.SalesOrderID
,soh.OrderDate
,sod.max_unit_price
FROM Sales.SalesOrderHeader AS soh
CROSS APPLY
(
SELECT
max_unit_price = MAX(sod.UnitPrice)
FROM Sales.SalesOrderDetail AS sod
WHERE soh.SalesOrderID = sod.SalesOrderID
) sod
当我们利用内部联接时此时JOIN中的查询是独立的所以需要进行GROUP BY,而对于CROSS APPLY它本身就是对来自左侧的表中每一行就行处理并返回,同时利用CROSS APPLY它也超越了相关子查询,比如说我们还需要查出每个订单的总价呢,我们利用相关子查询需要再次嵌入SELECT子句。
SELECT
SalesOrderID
,OrderDate
,MaxUnitPrice = (SELECT MAX(sod.UnitPrice) FROM Sales.SalesOrderDetail sod WHERE soh.SalesOrderID = sod.SalesOrderID)
,SumLineTotal = (SELECT SUM(LineTotal) FROM Sales.SalesOrderDetail sod WHERE soh.SalesOrderID = sod.SalesOrderID)
FROM Sales.SalesOrderHeader AS soh
而利用CROSS APPLY只需添加集合函数SUM即可
USE AdventureWorks2012
GO
SELECT
soh.SalesOrderID
,soh.OrderDate
,sod.max_unit_price
,sod.sum_line_total
FROM Sales.SalesOrderHeader AS soh
CROSS APPLY
(
SELECT
max_unit_price = MAX(sod.UnitPrice)
,sum_line_total = SUM(sod.LineTotal)
FROM Sales.SalesOrderDetail AS sod
WHERE soh.SalesOrderID = sod.SalesOrderID
) sod OUTER APPLY
对于OUTER APPLY,如果右侧的表表达式返回一个空集合,CROSS APPLY运算符不会返回相应的左侧行,也就是说OUTER APPLY和在派生表上进行LEFT JOIN是等同的,如下:
SELECT
soh.SalesOrderID
,soh.OrderDate
,sod.max_unit_price
FROM Sales.SalesOrderHeader AS soh
LEFT JOIN
(
SELECT
max_unit_price = MAX(sod.UnitPrice),
SalesOrderID
FROM Sales.SalesOrderDetail AS sod
GROUP BY sod.SalesOrderID
) sod
ON sod.SalesOrderID = soh.SalesOrderID
此时我们利用OUTER APPLY则是如下:
USE AdventureWorks2012
GO
SELECT
soh.SalesOrderID
,soh.OrderDate
,sod.max_unit_price
FROM Sales.SalesOrderHeader AS soh
OUTER APPLY
(
SELECT
max_unit_price = MAX(sod.UnitPrice)
FROM Sales.SalesOrderDetail AS sod
WHERE soh.SalesOrderID = sod.SalesOrderID
) sod
上述对于APPLY右侧表表达式是一个派生表,此时为了封装,我们可以使用TVF内嵌表值函数来实现。其实将内嵌表值函数来代替派生表实现每个客户最近的3个订单。首先我们封装一个表值函数
USE TSQL2012
GO
IF OBJECT_ID('dbo.TopOrders') IS NOT NULL
DROP FUNCTION dbo.TopOrders;
GO
CREATE FUNCTION dbo.TopOrders
(@custid AS INT, @n AS INT)
RETURNS TABLE
AS RETURN
SELECT orderid, empid, orderdate, requireddate
FROM Sales.Orders
WHERE custid = @custid
ORDER BY orderdate DESC, orderid DESC
OFFSET 0 ROWS FETCH FIRST @n ROWS ONLY;
GO
接着利用CROSS APPLY进行查询。
USE TSQL2012
GO
SELECT C.custid, C.companyname, A.orderid, A.empid, A.requireddate
FROM Sales.Customers AS C
CROSS APPLY dbo.TopOrders(C.custid, 3) AS A;