Excellent. You can actually have as many CTEs in a single query as you need. Each of them should be separated with a comma, and the WITH
keyword should only appear once, at the beginning.
WITH some_name1 AS ( your_cte1 ),
some_name2 AS ( your_cte2 ),
...
SELECT ...
Do remember that WITH
appears only once, at the beginning. The other CTEs are separated with commas. DO NOT put a comma after the last CTE.
Introducing multiple CTEs usually makes sense when they refer to each other. We'll get to know such CTEs in the next part. For now, we may think of other usages: for instance, you can use set operations like UNION
to show results from both CTEs. Suppose we want to show the top projects from two separate categories and some specific parameters, we could provide a query like this:
WITH succ_traveling AS (
SELECT
project_id,
category,
SUM(amount) AS sum_amount
FROM project
JOIN donation
ON donation.project_id = project.id
WHERE category = 'traveling'
GROUP BY project_id, category, minimal_amount
HAVING SUM(amount) >= 1.25 * minimal_amount),
succ_games AS (
SELECT
project_id,
category,
SUM(amount) AS sum_amount
FROM project
JOIN donation
ON donation.project_id = project.id
WHERE category = 'games'
GROUP BY project_id, category, minimal_amount
HAVING SUM(amount) >= 2 * minimal_amount)
SELECT
project_id,
category,
sum_amount
FROM succ_traveling
UNION
SELECT
project_id,
category,
sum_amount
FROM succ_games
ORDER BY sum_amount DESC;
In this example, we want to show projects with category traveling, which collected at least 25% more money than minimal_amount
and projects with category games, which collected at least twice as much money as they initially needed. Once we defined both CTEs, we could show all results together using UNION
in the outer query.