Introduction
Lately, I used APPLY
in SQL server that will really help you ease out many of the complex scenarios where you can write complex SQL queries in a simple way. This tip will put some light on APPLY
operator and when it's more preferable over regular join
.
Quote:
According to definition from https://technet.microsoft.com/en-us/library/ms175156%28v=sql.105%29.aspx:
The APPLY operator allows you to invoke a table-valued function for each row returned by an outer table expression of a query. The table-valued function acts as the right input and the outer table expression acts as the left input. The right input is evaluated for each row from the left input and the rows produced are combined for the final output. The list of columns produced by the APPLY operator is the set of columns in the left input followed by the list of columns returned by the right input.
So, basically it's a row-by-row join
of the left data-set with the right data-set. I will explain its basic syntax and then describe the scenario where APPLY
really helps ease out complexity.
Basically APPLY
has two forms, CROSS APPLY
and OUTER APPLY
. It's similar to JOIN
more or less but can do some more that makes it preferable in some scenarios.
APPLY
allows a correlated sub-query or table-valued function to be part of the FROM
clause.
Background
I read about it from https://technet.microsoft.com/en-us/library/ms175156%28v=sql.105%29.aspx. I just wanted to explain it in a simple way with an example.
Using the Code
SELECT *
FROM Employee E
INNER JOIN Department D ON E.DepartmentID = D.DepartmentID
SELECT *
FROM Employee E
CROSS APPLY (
SELECT *
FROM Department
WHERE Department.Departmentid = E.DepartmentID
) D
SELECT *
FROM Department E
LEFT JOIN Employee D ON E.DepartmentID = D.DepartmentID
SELECT *
FROM Department D
OUTER APPLY (
SELECT *
FROM Employee
WHERE Employee.Departmentid = D.DepartmentID
) E
SELECT EmployeeID
,FirstName
,(
SELECT Department.DepartmentID
FROM Department
WHERE DepartmentID = E.DepartmentID
) AS DepartmentID
FROM Employee E
CREATE FUNCTION dbo.fn_GetAllEmployeeOfADepartment (@DeptID AS INT)
RETURNS TABLE
AS
RETURN (
SELECT *
FROM Employee E
WHERE E.DepartmentID = @DeptID
)
SELECT *
FROM Department
CROSS APPLY fn_GetAllEmployeeOfADepartment(Department.DepartmentID)
SELECT *
FROM (
SELECT R.RunnerID
,FirstName
,LastName
,Email
,Distance
,EntryDate
,ROW_NUMBER() OVER (
PARTITION BY RR.RUNNERID ORDER BY RR.EntryDate DESC
) ROWID
FROM Runners R
INNER JOIN RunnersRecord rr ON R.RunnerID = RR.RunnerID
) AS T
WHERE T.ROWID <= 5
SELECT *
FROM Runners R
CROSS APPLY (
SELECT TOP 5 *
FROM RunnersRecord RR
WHERE R.RunnerID = RR.RunnerID
ORDER BY RR.EntryDate DESC) RR
SELECT *, (
SELECT TOP 1 RR.EntryDate
FROM RunnersRecord RR
WHERE V.RunnerID = RR.RunnerID ORDER BY Distance DESC) AS DayMostTravelled ,
(
SELECT TOP 1 RR.Distance
FROM RunnersRecord RR
WHERE V.RunnerID = RR.RunnerID ORDER BY Distance DESC
) AS LargestDistance
FROM Runners V
SELECT *
FROM Runners R
OUTER APPLY (
SELECT TOP 1 RR.EntryDate AS DayMostTravelled,Distance
FROM RunnersRecord RR
WHERE R.RunnerID = RR.RunnerID
ORDER BY Distance DESC
) CA
SELECT R.*, C.AvgDistance, C.TotalDistance, D.DistanceLeft
FROM Runners R
OUTER APPLY (
SELECT Avg(Distance) AS AvgDistance, Sum(Distance) AS TotalDistance
FROM RunnersRecord RR
WHERE R.RunnerID = RR.RunnerID
) C
OUTER APPLY
(
Select 500-C.TotalDistance as 'DistanceLeft'
) D
Conclusion
Apply
operator is just not an operator but an extension to SQL server that really helps out write complex logic in a simple query as discussed above. Comparing performance, it's slow due to row-by-row nature. For multi field expression, it's faster (but not that much). It's also useful while joining TVF
and used whenever you think of row-by-row logic. Hope it helps to understand Apply
operator in a very simplified way!
Thank you! Cheers. :)