Skip to content
This repository has been archived by the owner on Mar 11, 2021. It is now read-only.

Commit

Permalink
Use existing number sequences instead of looking them up again (#2299)
Browse files Browse the repository at this point in the history
In order to avoid a sequential table scan on the `work_items` DB table we take the already calculated values for the new `number_sequences` table from the old `work_item_number_sequences`.

Before this was the query plan for `INSERT` into the new `number_sequences` table:

```
EXPLAIN
SELECT space_id, 'work_items' "table_name", MAX(number) 
FROM work_items 
WHERE number IS NOT NULL 
GROUP BY 1,2;
+--------------------------------------------------------------------------------+
| QUERY PLAN                                                                     |
|--------------------------------------------------------------------------------|
| GroupAggregate  (cost=37097.49..38835.71 rows=37629 width=52)                  |
|   Group Key: space_id, 'work_items'::text                                      |
|   ->  Sort  (cost=37097.49..37437.97 rows=136193 width=52)                     |
|         Sort Key: space_id                                                     |
|         ->  Seq Scan on work_items  (cost=0.00..20824.93 rows=136193 width=52) |
|               Filter: (number IS NOT NULL)                                     |
+--------------------------------------------------------------------------------+
```

and now it is:

```
EXPLAIN
SELECT space_id, 'work_items' "table_name", current_val 
FROM work_item_number_sequences
GROUP BY 1,2;
+--------------------------------------------------------------------------------------------------------------------------------+
| QUERY PLAN                                                                                                                     |
|--------------------------------------------------------------------------------------------------------------------------------|
| Group  (cost=0.29..3541.66 rows=43872 width=52)                                                                                |
|   Group Key: space_id, 'work_items'::text                                                                                      |
|   ->  Index Scan using work_item_number_sequences_pkey on work_item_number_sequences  (cost=0.29..3322.30 rows=43872 width=52) |
+--------------------------------------------------------------------------------------------------------------------------------+
```

Thanks go out to @jarifibrahim for bringing my attention to this sequential table scan.

See #2291
  • Loading branch information
kwk authored Sep 26, 2018
1 parent cd7a01b commit 2a95482
Show file tree
Hide file tree
Showing 2 changed files with 10 additions and 6 deletions.
11 changes: 5 additions & 6 deletions migration/sql-files/106-number-sequences.sql
Original file line number Diff line number Diff line change
Expand Up @@ -6,9 +6,6 @@ CREATE TABLE number_sequences (
PRIMARY KEY (space_id, table_name)
);

-- Delete old number table
DROP TABLE work_item_number_sequences;

-- Update existing iterations and areas with new "number" column and fill in the
-- numbers in the order iterations and areas have been created.
ALTER TABLE iterations ADD COLUMN number INTEGER;
Expand All @@ -32,11 +29,13 @@ ALTER TABLE areas ADD CONSTRAINT areas_space_id_number_idx UNIQUE (space_id, num
-- Update the number_sequences table with the maximum for each table type

INSERT INTO number_sequences (space_id, table_name, current_val)
SELECT space_id, 'work_items' "table_name", MAX(number)
FROM work_items
WHERE number IS NOT NULL
SELECT space_id, 'work_items' "table_name", current_val
FROM work_item_number_sequences
GROUP BY 1,2;

-- Delete old number table
DROP TABLE work_item_number_sequences;

INSERT INTO number_sequences (space_id, table_name, current_val)
SELECT space_id, 'iterations' "table_name", MAX(number)
FROM iterations
Expand Down
5 changes: 5 additions & 0 deletions migration/sql-test-files/106-number-sequences.sql
Original file line number Diff line number Diff line change
Expand Up @@ -39,6 +39,11 @@ VALUES
(current_setting('wi3.id')::uuid, current_setting('wit.id')::uuid, current_setting('sp2.id')::uuid, '{"system.title":"WI3"}'::json, 1, '2018-09-17 12:01'),
(current_setting('wi4.id')::uuid, current_setting('wit.id')::uuid, current_setting('sp2.id')::uuid, '{"system.title":"WI4"}'::json, 2, '2018-09-17 17:01');

INSERT INTO work_item_number_sequences (space_id, current_val)
VALUES
(current_setting('sp1.id')::uuid, 2),
(current_setting('sp2.id')::uuid, 2);

INSERT INTO iterations (id, name, path, space_id, created_at)
VALUES
(current_setting('iter1.id')::uuid, 'iteration 1', replace(current_setting('iter1.id'), '-', '_')::ltree, current_setting('sp1.id')::uuid, '2018-09-17 16:01'),
Expand Down

0 comments on commit 2a95482

Please sign in to comment.