Skip to content

Commit

Permalink
Issue 282: Fix check of NOT NULL by repack.primary_keys (#376)
Browse files Browse the repository at this point in the history
PostgreSQL 11 introduced covering indexes. pg_repack couldn't
use indexes which include additional columns because all
columns are listed in `pg_index.indkey`. To overcome this
it is necessary to consider `pg_index.indnkeyatts` value.
  • Loading branch information
za-arthur committed Feb 28, 2024
1 parent 3ecda64 commit 6a3c282
Show file tree
Hide file tree
Showing 14 changed files with 372 additions and 58 deletions.
4 changes: 2 additions & 2 deletions META.json
Original file line number Diff line number Diff line change
Expand Up @@ -2,7 +2,7 @@
"name": "pg_repack",
"abstract": "PostgreSQL module for data reorganization",
"description": "Reorganize tables in PostgreSQL databases with minimal locks",
"version": "1.5.0",
"version": "1.5.1",
"maintainer": [
"Beena Emerson <[email protected]>",
"Josh Kupershmidt <[email protected]>",
Expand All @@ -17,7 +17,7 @@
"provides": {
"pg_repack": {
"file": "lib/pg_repack.sql",
"version": "1.5.0",
"version": "1.5.1",
"abstract": "Reorganize tables in PostgreSQL databases with minimal locks"
}
},
Expand Down
50 changes: 36 additions & 14 deletions lib/pg_repack.sql.in
Original file line number Diff line number Diff line change
Expand Up @@ -247,20 +247,42 @@ $$
LANGUAGE sql STABLE STRICT;

-- includes not only PRIMARY KEYS but also UNIQUE NOT NULL keys
CREATE VIEW repack.primary_keys AS
SELECT indrelid, min(indexrelid) AS indexrelid
FROM (SELECT indrelid, indexrelid FROM pg_index
WHERE indisunique
AND indisvalid
AND indpred IS NULL
AND 0 <> ALL(indkey)
AND NOT EXISTS(
SELECT 1 FROM pg_attribute
WHERE attrelid = indrelid
AND attnum = ANY(indkey)
AND NOT attnotnull)
ORDER BY indrelid, indisprimary DESC, indnatts, indkey) tmp
GROUP BY indrelid;
DO $$
BEGIN
IF current_setting('server_version_num')::int >= 110000 THEN
CREATE VIEW repack.primary_keys AS
SELECT indrelid, min(indexrelid) AS indexrelid
FROM (SELECT indrelid, indexrelid FROM pg_index
WHERE indisunique
AND indisvalid
AND indpred IS NULL
AND 0 <> ALL(indkey)
AND NOT EXISTS(
SELECT 1 FROM pg_attribute
WHERE attrelid = indrelid
-- indkey is 0-based int2vector
AND attnum = ANY(indkey[0:indnkeyatts - 1])
AND NOT attnotnull)
ORDER BY indrelid, indisprimary DESC, indnatts, indkey) tmp
GROUP BY indrelid;
ELSE
CREATE VIEW repack.primary_keys AS
SELECT indrelid, min(indexrelid) AS indexrelid
FROM (SELECT indrelid, indexrelid FROM pg_index
WHERE indisunique
AND indisvalid
AND indpred IS NULL
AND 0 <> ALL(indkey)
AND NOT EXISTS(
SELECT 1 FROM pg_attribute
WHERE attrelid = indrelid
AND attnum = ANY(indkey)
AND NOT attnotnull)
ORDER BY indrelid, indisprimary DESC, indnatts, indkey) tmp
GROUP BY indrelid;
END IF;
END;
$$;

CREATE VIEW repack.tables AS
SELECT repack.oid2text(R.oid) AS relname,
Expand Down
87 changes: 48 additions & 39 deletions regress/expected/after-schema.out
Original file line number Diff line number Diff line change
Expand Up @@ -2,73 +2,82 @@
-- tables schema after running repack
--
\d tbl_cluster
Table "public.tbl_cluster"
Column | Type | Modifiers
--------+-----------------------------+-----------
col1 | integer | not null
time | timestamp without time zone |
,") | text | not null
Table "public.tbl_cluster"
Column | Type | Collation | Nullable | Default
--------+-----------------------------+-----------+----------+---------
col1 | integer | | not null |
time | timestamp without time zone | | |
,") | text | | not null |
Indexes:
"tbl_cluster_pkey" PRIMARY KEY, btree (","")", col1) WITH (fillfactor='75')
",") cluster" btree ("time", length(","")"), ","")" text_pattern_ops) WITH (fillfactor='75') CLUSTER

\d tbl_gistkey
Table "public.tbl_gistkey"
Column | Type | Modifiers
--------+---------+-----------
id | integer | not null
c | circle |
Table "public.tbl_gistkey"
Column | Type | Collation | Nullable | Default
--------+---------+-----------+----------+---------
id | integer | | not null |
c | circle | | |
Indexes:
"tbl_gistkey_pkey" PRIMARY KEY, btree (id)
"cidx_circle" gist (c) CLUSTER

\d tbl_only_ckey
Table "public.tbl_only_ckey"
Column | Type | Modifiers
--------+-----------------------------+-----------
col1 | integer |
col2 | timestamp without time zone |
,") | text |
Table "public.tbl_only_ckey"
Column | Type | Collation | Nullable | Default
--------+-----------------------------+-----------+----------+---------
col1 | integer | | |
col2 | timestamp without time zone | | |
,") | text | | |
Indexes:
"cidx_only_ckey" btree (col2, ","")") CLUSTER

\d tbl_only_pkey
Table "public.tbl_only_pkey"
Column | Type | Modifiers
--------+---------+-----------
col1 | integer | not null
,") | text |
Table "public.tbl_only_pkey"
Column | Type | Collation | Nullable | Default
--------+---------+-----------+----------+---------
col1 | integer | | not null |
,") | text | | |
Indexes:
"tbl_only_pkey_pkey" PRIMARY KEY, btree (col1)

\d tbl_incl_pkey
Table "public.tbl_incl_pkey"
Column | Type | Collation | Nullable | Default
--------+-----------------------------+-----------+----------+---------
col1 | integer | | not null |
col2 | timestamp without time zone | | |
Indexes:
"tbl_incl_pkey_pkey" PRIMARY KEY, btree (col1) INCLUDE (col2)

\d tbl_with_dropped_column
Table "public.tbl_with_dropped_column"
Column | Type | Modifiers
--------+---------+-----------
c1 | text |
id | integer | not null
c2 | text |
c3 | text |
Table "public.tbl_with_dropped_column"
Column | Type | Collation | Nullable | Default
--------+---------+-----------+----------+---------
c1 | text | | |
id | integer | | not null |
c2 | text | | |
c3 | text | | |
Indexes:
"tbl_with_dropped_column_pkey" PRIMARY KEY, btree (id) WITH (fillfactor='75') CLUSTER
"idx_c1c2" btree (c1, c2) WITH (fillfactor='75')
"idx_c2c1" btree (c2, c1)

\d tbl_with_dropped_toast
Table "public.tbl_with_dropped_toast"
Column | Type | Modifiers
--------+---------+-----------
i | integer | not null
j | integer | not null
Table "public.tbl_with_dropped_toast"
Column | Type | Collation | Nullable | Default
--------+---------+-----------+----------+---------
i | integer | | not null |
j | integer | | not null |
Indexes:
"tbl_with_dropped_toast_pkey" PRIMARY KEY, btree (i, j) CLUSTER

\d tbl_idxopts
Table "public.tbl_idxopts"
Column | Type | Modifiers
--------+---------+-----------
i | integer | not null
t | text |
Table "public.tbl_idxopts"
Column | Type | Collation | Nullable | Default
--------+---------+-----------+----------+---------
i | integer | | not null |
t | text | | |
Indexes:
"tbl_idxopts_pkey" PRIMARY KEY, btree (i)
"idxopts_t" btree (t DESC NULLS LAST) WHERE t <> 'aaa'::text
Expand Down
7 changes: 7 additions & 0 deletions regress/expected/after-schema_1.out
Original file line number Diff line number Diff line change
Expand Up @@ -41,6 +41,13 @@ Indexes:
Indexes:
"tbl_only_pkey_pkey" PRIMARY KEY, btree (col1)

\d tbl_incl_pkey
Table "public.tbl_incl_pkey"
Column | Type | Collation | Nullable | Default
--------+-----------------------------+-----------+----------+---------
col1 | integer | | |
col2 | timestamp without time zone | | |

\d tbl_with_dropped_column
Table "public.tbl_with_dropped_column"
Column | Type | Collation | Nullable | Default
Expand Down
82 changes: 82 additions & 0 deletions regress/expected/after-schema_2.out
Original file line number Diff line number Diff line change
@@ -0,0 +1,82 @@
--
-- tables schema after running repack
--
\d tbl_cluster
Table "public.tbl_cluster"
Column | Type | Modifiers
--------+-----------------------------+-----------
col1 | integer | not null
time | timestamp without time zone |
,") | text | not null
Indexes:
"tbl_cluster_pkey" PRIMARY KEY, btree (","")", col1) WITH (fillfactor='75')
",") cluster" btree ("time", length(","")"), ","")" text_pattern_ops) WITH (fillfactor='75') CLUSTER

\d tbl_gistkey
Table "public.tbl_gistkey"
Column | Type | Modifiers
--------+---------+-----------
id | integer | not null
c | circle |
Indexes:
"tbl_gistkey_pkey" PRIMARY KEY, btree (id)
"cidx_circle" gist (c) CLUSTER

\d tbl_only_ckey
Table "public.tbl_only_ckey"
Column | Type | Modifiers
--------+-----------------------------+-----------
col1 | integer |
col2 | timestamp without time zone |
,") | text |
Indexes:
"cidx_only_ckey" btree (col2, ","")") CLUSTER

\d tbl_only_pkey
Table "public.tbl_only_pkey"
Column | Type | Modifiers
--------+---------+-----------
col1 | integer | not null
,") | text |
Indexes:
"tbl_only_pkey_pkey" PRIMARY KEY, btree (col1)

\d tbl_incl_pkey
Table "public.tbl_incl_pkey"
Column | Type | Modifiers
--------+-----------------------------+-----------
col1 | integer |
col2 | timestamp without time zone |

\d tbl_with_dropped_column
Table "public.tbl_with_dropped_column"
Column | Type | Modifiers
--------+---------+-----------
c1 | text |
id | integer | not null
c2 | text |
c3 | text |
Indexes:
"tbl_with_dropped_column_pkey" PRIMARY KEY, btree (id) WITH (fillfactor='75') CLUSTER
"idx_c1c2" btree (c1, c2) WITH (fillfactor='75')
"idx_c2c1" btree (c2, c1)

\d tbl_with_dropped_toast
Table "public.tbl_with_dropped_toast"
Column | Type | Modifiers
--------+---------+-----------
i | integer | not null
j | integer | not null
Indexes:
"tbl_with_dropped_toast_pkey" PRIMARY KEY, btree (i, j) CLUSTER

\d tbl_idxopts
Table "public.tbl_idxopts"
Column | Type | Modifiers
--------+---------+-----------
i | integer | not null
t | text |
Indexes:
"tbl_idxopts_pkey" PRIMARY KEY, btree (i)
"idxopts_t" btree (t DESC NULLS LAST) WHERE t <> 'aaa'::text

1 change: 1 addition & 0 deletions regress/expected/error-on-invalid-idx.out
Original file line number Diff line number Diff line change
Expand Up @@ -12,6 +12,7 @@ WARNING: Invalid index: CREATE UNIQUE INDEX idx_badindex_n ON public.tbl_badinde
INFO: repacking table "public.tbl_cluster"
INFO: repacking table "public.tbl_gistkey"
INFO: repacking table "public.tbl_idxopts"
INFO: repacking table "public.tbl_incl_pkey"
INFO: repacking table "public.tbl_only_pkey"
INFO: repacking table "public.tbl_order"
INFO: repacking table "public.tbl_storage_plain"
Expand Down
10 changes: 10 additions & 0 deletions regress/expected/error-on-invalid-idx_1.out
Original file line number Diff line number Diff line change
Expand Up @@ -9,3 +9,13 @@ WARNING: Invalid index: CREATE UNIQUE INDEX idx_badindex_n ON public.tbl_badinde
\! pg_repack --dbname=contrib_regression --error-on-invalid-index
INFO: repacking table "public.tbl_badindex"
WARNING: Invalid index: CREATE UNIQUE INDEX idx_badindex_n ON public.tbl_badindex USING btree (n)
INFO: repacking table "public.tbl_cluster"
INFO: repacking table "public.tbl_gistkey"
INFO: repacking table "public.tbl_idxopts"
INFO: repacking table "public.tbl_only_pkey"
INFO: repacking table "public.tbl_order"
INFO: repacking table "public.tbl_storage_plain"
INFO: repacking table "public.tbl_with_dropped_column"
INFO: repacking table "public.tbl_with_dropped_toast"
INFO: repacking table "public.tbl_with_mod_column_storage"
INFO: repacking table "public.tbl_with_toast"
7 changes: 7 additions & 0 deletions regress/expected/repack-check.out
Original file line number Diff line number Diff line change
Expand Up @@ -23,6 +23,13 @@ SELECT * FROM tbl_only_pkey ORDER BY 1;
2 | def
(2 rows)

SELECT * FROM tbl_incl_pkey ORDER BY 1;
col1 | col2
------+--------------------------
1 | Tue Jan 01 00:00:00 2008
2 | Fri Feb 01 00:00:00 2008
(2 rows)

SELECT * FROM tbl_gistkey ORDER BY 1;
id | c
----+-----------
Expand Down
5 changes: 3 additions & 2 deletions regress/expected/repack-run.out
Original file line number Diff line number Diff line change
Expand Up @@ -5,13 +5,14 @@
INFO: repacking table "public.tbl_cluster"
\! pg_repack --dbname=contrib_regression --table=tbl_badindex
INFO: repacking table "public.tbl_badindex"
WARNING: skipping invalid index: CREATE UNIQUE INDEX idx_badindex_n ON tbl_badindex USING btree (n)
WARNING: skipping invalid index: CREATE UNIQUE INDEX idx_badindex_n ON public.tbl_badindex USING btree (n)
\! pg_repack --dbname=contrib_regression
INFO: repacking table "public.tbl_badindex"
WARNING: skipping invalid index: CREATE UNIQUE INDEX idx_badindex_n ON tbl_badindex USING btree (n)
WARNING: skipping invalid index: CREATE UNIQUE INDEX idx_badindex_n ON public.tbl_badindex USING btree (n)
INFO: repacking table "public.tbl_cluster"
INFO: repacking table "public.tbl_gistkey"
INFO: repacking table "public.tbl_idxopts"
INFO: repacking table "public.tbl_incl_pkey"
INFO: repacking table "public.tbl_only_pkey"
INFO: repacking table "public.tbl_order"
INFO: repacking table "public.tbl_storage_plain"
Expand Down
8 changes: 8 additions & 0 deletions regress/expected/repack-setup.out
Original file line number Diff line number Diff line change
Expand Up @@ -21,6 +21,12 @@ CREATE TABLE tbl_only_ckey (
) WITH (fillfactor = 70);
CREATE INDEX cidx_only_ckey ON tbl_only_ckey (col2, ","")");
ALTER TABLE tbl_only_ckey CLUSTER ON cidx_only_ckey;
CREATE TABLE tbl_incl_pkey (
col1 int,
col2 timestamp
);
-- Covering indexes were added only in PostgreSQL 11
ALTER TABLE tbl_incl_pkey ADD PRIMARY KEY (col1) INCLUDE (col2);
CREATE TABLE tbl_gistkey (
id integer PRIMARY KEY,
c circle
Expand Down Expand Up @@ -85,6 +91,8 @@ INSERT INTO tbl_only_pkey VALUES(1, 'abc');
INSERT INTO tbl_only_pkey VALUES(2, 'def');
INSERT INTO tbl_only_ckey VALUES(1, '2008-01-01 00:00:00', 'abc');
INSERT INTO tbl_only_ckey VALUES(2, '2008-02-01 00:00:00', 'def');
INSERT INTO tbl_incl_pkey VALUES(1, '2008-01-01 00:00:00');
INSERT INTO tbl_incl_pkey VALUES(2, '2008-02-01 00:00:00');
INSERT INTO tbl_gistkey VALUES(1, '<(1,2),3>');
INSERT INTO tbl_gistkey VALUES(2, '<(4,5),6>');
INSERT INTO tbl_with_dropped_column VALUES('d1', 'c1', 2, 'd2', 'c2', 'd3');
Expand Down
Loading

0 comments on commit 6a3c282

Please sign in to comment.