Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
Use Postgres CTE to update iteration numbers (fabric8-services#2319)
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