Skip to content

Commit

Permalink
Use Postgres CTE to update iteration numbers (fabric8-services#2319)
Browse files Browse the repository at this point in the history
Use Postgres CTE to update iteration numbers

When explaining the updae before it looks like this:

```
postgres@172:postgres> explain UPDATE iterations iter SET number = seq.row_number
                       FROM (
                           SELECT id, space_id, created_at, row_number() OVER (PARTITION BY space_id ORDER BY created_at ASC)
                           FROM iterations
                       ) AS seq
                       WHERE iter.space_id = seq.space_id AND iter.id = seq.id;
+-----------------------------------------------------------------------------------------+
| QUERY PLAN                                                                              |
|-----------------------------------------------------------------------------------------|
| Update on iterations iter  (cost=2.06..2.16 rows=1 width=263)                           |
|   ->  Merge Join  (cost=2.06..2.16 rows=1 width=263)                                    |
|         Merge Cond: (seq.space_id = iter.space_id)                                      |
|         Join Filter: (iter.id = seq.id)                                                 |
|         ->  Subquery Scan on seq  (cost=1.03..1.09 rows=2 width=112)                    |
|               ->  WindowAgg  (cost=1.03..1.07 rows=2 width=48)                          |
|                     ->  Sort  (cost=1.03..1.03 rows=2 width=40)                         |
|                           Sort Key: iterations.space_id, iterations.created_at          |
|                           ->  Seq Scan on iterations  (cost=0.00..1.02 rows=2 width=40) |
|         ->  Sort  (cost=1.03..1.03 rows=2 width=187)                                    |
|               Sort Key: iter.space_id                                                   |
|               ->  Seq Scan on iterations iter  (cost=0.00..1.02 rows=2 width=187)       |
+-----------------------------------------------------------------------------------------+
```

Now the update looks better (notice absence of nested seq scans):

```
postgres@172:postgres> explain WITH iteration_numbers AS (
                           SELECT *, ROW_NUMBER() OVER(PARTITION BY space_id ORDER BY created_at ASC) AS num
                           FROM iterations
                       )
                       UPDATE iterations SET number = (SELECT num FROM iteration_numbers WHERE iteration_numbers.id = iterations.id);
+---------------------------------------------------------------------------------------------+
| QUERY PLAN                                                                                  |
|---------------------------------------------------------------------------------------------|
| Update on iterations  (cost=1.07..2.18 rows=2 width=191)                                    |
|   CTE iteration_numbers                                                                     |
|     ->  WindowAgg  (cost=1.03..1.07 rows=2 width=193)                                       |
|           ->  Sort  (cost=1.03..1.03 rows=2 width=185)                                      |
|                 Sort Key: iterations_1.space_id, iterations_1.created_at                    |
|                 ->  Seq Scan on iterations iterations_1  (cost=0.00..1.02 rows=2 width=185) |
|   ->  Seq Scan on iterations  (cost=0.00..1.11 rows=2 width=191)                            |
|         SubPlan 2                                                                           |
|           ->  CTE Scan on iteration_numbers  (cost=0.00..0.04 rows=1 width=8)               |
|                 Filter: (id = iterations.id)                                                |
+---------------------------------------------------------------------------------------------+
```
  • Loading branch information
kwk authored Oct 15, 2018
1 parent 37a913a commit e09b805
Showing 1 changed file with 7 additions and 8 deletions.
Original file line number Diff line number Diff line change
@@ -1,11 +1,10 @@
-- Assign a number to every existing iteration partitioned by their space and in
-- ascending creation order.
UPDATE iterations SET number = seq.row_number
FROM (
SELECT id, space_id, created_at, row_number() OVER (PARTITION BY space_id ORDER BY created_at ASC)
--- Assign a number to every existing iteration partitioned by their space and in
--- ascending creation order.
WITH iteration_numbers AS (
SELECT *, ROW_NUMBER() OVER(PARTITION BY space_id ORDER BY created_at ASC) AS num
FROM iterations
) AS seq
WHERE iterations.id = seq.id;
)
UPDATE iterations SET number = (SELECT num FROM iteration_numbers WHERE iteration_numbers.id = iterations.id);

-- Make "number" a required column and add an index for faster querying over
-- "space_id" and "number".
Expand All @@ -17,4 +16,4 @@ INSERT INTO number_sequences (space_id, table_name, current_val)
SELECT space_id, 'iterations' "table_name", MAX(number)
FROM iterations
WHERE number IS NOT NULL
GROUP BY 1,2;
GROUP BY 1,2;

0 comments on commit e09b805

Please sign in to comment.