46
loading...
This website collects cookies to deliver better user experience
-- create a CTE
WITH cte_greeting
AS (
SELECT 'Hello World!' as 'greeting'
)
-- use the CTE
SELECT * FROM cte_greeting;
/*
greeting
------------
Hello World!
*/
WITH <cte_name> (<optional_list_of_column_names>)
AS (
<query_definition>
)
SELECT <list of columns> FROM <cte_name>;
WITH cte_greeting
AS (
SELECT 'Hello World!'
)
SELECT * FROM cte_greeting;
/*
No column name was specified for column 1 of 'cte_greeting'.
*/
WITH cte_greeting( my_greeting )
AS (
SELECT 'Hello World!'
)
SELECT * FROM cte_greeting;
/*
my_greeting
------------
Hello World!
*/
WITH cte_greeting( my_greeting )
AS (
SELECT 'Hello World!' as 'greeting'
)
SELECT * FROM cte_greeting;
/*
my_greeting
-----------------
Hello World!
*/
WITH cte_greeting( my_greeting )
AS (
SELECT 'Hello World!' as 'greeting1', 'Good Morning!' as 'greeting2'
)
SELECT * FROM cte_greeting;
/*
'cte_greeting' has more columns than were specified in the column list.
*/
WITH cte_greeting( my_greeting )
AS (
SELECT 'Hello World!'
)
SELECT 'some other sql statement'
SELECT * FROM cte_greeting
/*
Common table expression defined but not used.
*/
WITH cte_greeting1( greeting1 )
AS (
SELECT 'Hello World!'
),
cte_greeting2( greeting2 )
AS (
SELECT 'Good Morning!'
)
SELECT greeting1 as 'greetings' FROM cte_greeting1
UNION
SELECT greeting2 as 'greetings' FROM cte_greeting2
/*
greetings
------------------
Hello World!
Good Morning!
*/
CREATE TABLE tblMarvelMovies (
id INT IDENTITY(1,1) PRIMARY KEY,
name varchar(50),
rating DECIMAL(2,1),
gross_revenue_millions DECIMAL(5,2)
);
INSERT tblMarvelMovies (name, rating, gross_revenue_millions)
VALUES ('Avengers: Endgame', 7.1, 777.27)
INSERT tblMarvelMovies (name, rating, gross_revenue_millions)
VALUES ('Avengers: Infinity War', 8.9, 560.13)
INSERT tblMarvelMovies (name, rating, gross_revenue_millions)
VALUES ('Avengers: Age of Ultron', 6.0, 874.85)
INSERT tblMarvelMovies (name, rating, gross_revenue_millions)
VALUES ('The Avengers', 6.1, 918.44)
INSERT tblMarvelMovies (name, rating, gross_revenue_millions)
VALUES ('Iron Man', 8.5, 918.75)
INSERT tblMarvelMovies (name, rating, gross_revenue_millions)
VALUES ('Iron Man 2', 7.1, 798.97)
INSERT tblMarvelMovies (name, rating, gross_revenue_millions)
VALUES ('Iron Man 3', 6.4, 524.08)
INSERT tblMarvelMovies (name, rating, gross_revenue_millions)
VALUES ('Guardians of the Galaxy', 8.7, 711.11)
INSERT tblMarvelMovies (name, rating, gross_revenue_millions)
VALUES ('Guardians of the Galaxy Vol. 2', 8.2, 963.13)
INSERT tblMarvelMovies (name, rating, gross_revenue_millions)
VALUES ('Thor', 6.1, 871.70)
INSERT tblMarvelMovies (name, rating, gross_revenue_millions)
VALUES ('Thor: The Dark World', 6.1, 898.57)
INSERT tblMarvelMovies (name, rating, gross_revenue_millions)
VALUES ('Thor: Ragnarok', 6.4, 841.32)
INSERT tblMarvelMovies (name, rating, gross_revenue_millions)
VALUES ('Captain America: The First Avenger', 9.5, 938.28)
INSERT tblMarvelMovies (name, rating, gross_revenue_millions)
VALUES ('Captain America: The Winter Soldier', 8.7, 868.83)
INSERT tblMarvelMovies (name, rating, gross_revenue_millions)
VALUES ('Captain America: Civil War', 8.3, 855.60)
SELECT
series_category,
SUM(gross_revenue_millions) as 'total_gross_revenue',
CAST(AVG(rating) as DECIMAL(2,1)) as 'avg_rating'
FROM (
SELECT
CASE
WHEN name like '%Avengers%' THEN 'The Avengers'
WHEN name like '%Iron Man%' THEN 'Iron Man'
WHEN name like '%Guardians%' THEN 'Guardians of the Galaxy'
WHEN name like '%Thor%' THEN 'Thor'
WHEN name like '%Captain%' THEN 'Captain America'
END as 'series_category',
gross_revenue_millions,
rating
FROM tblMarvelMovies
) temp
GROUP BY series_category
ORDER BY avg_rating desc;
/*
series_category total_gross_revenue avg_rating
---------------------------- ---------------------- -----------
Captain America 2662.71 8.8
Guardians of the Galaxy 1674.24 8.5
Iron Man 2241.80 7.3
The Avengers 3130.69 7.0
Thor 2611.59 6.2
*/
-- complex logic encapsulated within CTE
WITH cte_series
AS (
SELECT
CASE
WHEN name like '%Avengers%' THEN 'The Avengers'
WHEN name like '%Iron Man%' THEN 'Iron Man'
WHEN name like '%Guardians%' THEN 'Guardians of the Galaxy'
WHEN name like '%Thor%' THEN 'Thor'
WHEN name like '%Captain%' THEN 'Captain America'
END as 'series_category',
gross_revenue_millions,
rating
FROM tblMarvelMovies
)
-- simpler and more readable main query
SELECT
series_category,
SUM(gross_revenue_millions) as 'total_gross_revenue',
CAST(AVG(rating) as DECIMAL(2,1)) as 'avg_rating'
FROM cte_series
GROUP BY series_category
ORDER BY avg_rating desc;
/*
series_category total_gross_revenue avg_rating
---------------------------- ---------------------- -----------
Captain America 2662.71 8.8
Guardians of the Galaxy 1674.24 8.5
Iron Man 2241.80 7.3
The Avengers 3130.69 7.0
Thor 2611.59 6.2
*/
WITH cte_recursive( sequence )
AS (
-- anchor member
SELECT 1 as 'sequence'
UNION ALL
-- recursive member
SELECT (sequence+1) as 'sequence'
FROM cte_recursive
WHERE sequence < 10 -- termination condition
)
SELECT * FROM cte_recursive;
/*
sequence
----------------
1
2
3
4
5
6
7
8
9
10
*/
Result set T0 ( returned by anchor member )
sequence
--------------
1
Iteration 1 - Result set T1
sequence
--------------
2
Iteration 2 - Result set T2
sequence
--------------
3
...
...
...
Iteration 9 - Result set T9
sequence
--------------
10
Iteration 10 ( termination condition ends recursion )
sequence
----------------
1
2
3
4
5
6
7
8
9
10
WITH cte_recursive( sequence )
AS (
-- anchor member
SELECT 1 as 'sequence'
UNION ALL
-- recursive member
SELECT (sequence+1) as 'sequence'
FROM cte_recursive
)
SELECT * FROM cte_recursive;
MAXRECURSION
query hint which we can specify using the OPTION
clause. Lets set the max recursion limit to a lower value like 10 and see what happens.WITH cte_recursive( sequence )
AS (
-- anchor member
SELECT 1 as 'sequence'
UNION ALL
-- recursive member
SELECT (sequence+1) as 'sequence'
FROM cte_recursive
)
SELECT * FROM cte_recursive
OPTION ( MAXRECURSION 10 );
WITH cte_recursive( sequence, anchor_member )
AS (
-- anchor member 1
SELECT 5 as 'sequence', 'first' as 'anchor_member'
UNION
-- anchor member 2
SELECT 8 as 'sequence', 'second' as 'anchor_member'
UNION ALL
-- recursive member
SELECT (sequence+1) as 'sequence', anchor_member
FROM cte_recursive
WHERE sequence < 10 -- termination condition
)
SELECT * FROM cte_recursive;
/*
sequence anchor_member
---------------- -------------
5 first
8 second
9 second
10 second
6 first
7 first
8 first
9 first
10 first
*/
anchor_member
column helps identify which anchor member's result set is being recursed over. The recursive member first operates on the result set of the second anchor member. After completely recursing over the second anchor member, it moves on to the first one.WITH cte_recursive( sequence, recursive_member, iteration )
AS (
-- anchor member
SELECT
1 as 'sequence',
cast('' as varchar(10)) as 'recursive_member',
0 as iteration
UNION ALL
-- recursive member 1
SELECT
(sequence+1) as 'sequence',
cast('first' as varchar(10)) as 'recursive_member',
(iteration+1) as iteration
FROM cte_recursive
WHERE sequence < 4 -- termination condition
UNION ALL
-- recursive member 2
SELECT
(sequence+1) as 'sequence',
cast('second' as varchar(10)) as 'recursive_member',
(iteration+1) as iteration
FROM cte_recursive
WHERE sequence < 4 -- termination condition
)
SELECT * FROM cte_recursive;
/*
sequence recursive_member iteration
---------------- ---------------- -----------
1 0
2 first 1
2 second 1
3 first 2
3 second 2
4 first 3
4 second 3
4 first 3
4 second 3
3 first 2
3 second 2
4 first 3
4 second 3
4 first 3
4 second 3
*/
CAST()
for the recursive_member
columns? That is because the CTE is not aware of the datatype and length of the literal values we have used as column values so we must specify that else it'll throw an error. Go ahead and remove those CAST()
calls and see what the error is all about.T0
sequence recursive_member iteration
---------------- ---------------- -----------
1 0
T1
sequence recursive_member iteration
---------------- ---------------- -----------
2 first 1
2 second 1
T2
sequence recursive_member iteration
---------------- ---------------- -----------
3 first 2
3 second 2
T3
sequence recursive_member iteration
---------------- ---------------- -----------
4 first 3
4 second 3
T4
sequence recursive_member iteration
---------------- ---------------- -----------
4 first 3
4 second 3
T5
sequence recursive_member iteration
---------------- ---------------- -----------
3 first 2
3 second 2
T6
sequence recursive_member iteration
---------------- ---------------- -----------
4 first 3
4 second 3
T7
sequence recursive_member iteration
---------------- ---------------- -----------
4 first 3
4 second 3
CREATE TABLE tblEmployees (
emp_id INT IDENTITY(1,1) PRIMARY KEY,
name varchar(50) NOT NULL,
designation varchar(50) NOT NULL,
manager_id INT NULL
);
SET IDENTITY_INSERT tblEmployees ON;
INSERT INTO tblEmployees(emp_id, name, designation, manager_id)
VALUES( 1, 'Michael Scott', 'Regional Manager', 9 );
INSERT INTO tblEmployees(emp_id, name, designation, manager_id)
VALUES( 2, 'Dwight Schrute', 'Assistant to the Regional Manager', 1 );
INSERT INTO tblEmployees(emp_id, name, designation, manager_id)
VALUES( 3, 'Jim Halpert', 'Salesman', 1 );
INSERT INTO tblEmployees(emp_id, name, designation, manager_id)
VALUES( 4, 'Pam Beasley', 'Receptionist', 1 );
INSERT INTO tblEmployees(emp_id, name, designation, manager_id)
VALUES( 5, 'Kevin Malone', 'Accountant', 6 );
INSERT INTO tblEmployees(emp_id, name, designation, manager_id)
VALUES( 6, 'Angela Martin', 'Head Accountant', 1 );
INSERT INTO tblEmployees(emp_id, name, designation, manager_id)
VALUES( 7, 'Oscar Gutierrez', 'Accountant', 6 );
INSERT INTO tblEmployees(emp_id, name, designation, manager_id)
VALUES( 8, 'David Wallace', 'CEO', NULL );
INSERT INTO tblEmployees(emp_id, name, designation, manager_id)
VALUES( 9, 'Jan', 'Vice-President', 8 );
SET IDENTITY_INSERT tblEmployees OFF;
WITH cte_emp_levels( emp_id, name, designation, manager_id, level )
AS (
-- anchor member
SELECT emp_id, name, designation, manager_id, 0 as 'level'
FROM tblEmployees
WHERE manager_id IS NULL
UNION ALL
-- recursive member
SELECT e.emp_id, e.name, e.designation, e.manager_id, ( level + 1 ) as 'level'
FROM tblEmployees e
INNER JOIN cte_emp_levels c ON e.manager_id = c.emp_id
)
SELECT * FROM cte_emp_levels;
T0 - result set returned by anchor member
emp_id name designation manager_id level
---------------- --------------- ------------ ----------- -----------
8 David Wallace CEO NULL 0
T1
emp_id name designation manager_id level
---------------- ------ ---------------- ----------- -----------
9 Jan Vice-President 8 1
T2
emp_id name designation manager_id level
---------------- --------------- ------------------- ----------- -----------
1 Michael Scott Regional Manager 9 2
T3
emp_id name designation manager_id level
---------------- --------------- ----------------------------------- ----------- -----------
2 Dwight Schrute Assistant to the Regional Manager 1 3
3 Jim Halpert Salesman 1 3
4 Pam Beasley Receptionist 1 3
6 Angela Martin Head Accountant 1 3
T4
emp_id name designation manager_id level
---------------- ------------------- --------------- ----------- -----------
5 Kevin Malone Accountant 6 4
7 Oscar Gutierrez Accountant 6 4