Fix a bug of automatic index creation (#40)

It is intended that a unique index is created only if all primary
keys of tables in FROM clause appear in the target list. For this
purpose, pull_varnos_of_level was used to extract relations in the
FROM clause, but it is incorrect and actually we should use
get_relids_in_jointree.

Due to this bug, an index could be created even even where there
is a pkey attribute from just one of relations in FROM clause.
This commit is contained in:
Yugo Nagata 2022-12-16 12:42:35 +09:00 committed by GitHub
parent 59081de628
commit 326720874e
No known key found for this signature in database
GPG key ID: 4AEE18F83AFDEB23
3 changed files with 74 additions and 12 deletions

View file

@ -31,6 +31,7 @@
#include "nodes/nodeFuncs.h"
#include "nodes/pathnodes.h"
#include "optimizer/optimizer.h"
#include "optimizer/prep.h"
#include "parser/parser.h"
#include "parser/parsetree.h"
#include "parser/parse_clause.h"
@ -1287,9 +1288,6 @@ get_primary_key_attnos_from_query(Query *query, List **constraintList, bool is_c
int i;
Bitmapset *keys = NULL;
Relids rels_in_from;
#if defined(PG_VERSION_NUM) && (PG_VERSION_NUM >= 140000)
PlannerInfo root;
#endif
/*
* Collect primary key attributes from all tables used in query. The key attributes
@ -1341,28 +1339,25 @@ get_primary_key_attnos_from_query(Query *query, List **constraintList, bool is_c
if (IsA(tle->expr, Var))
{
Var *var = (Var*) tle->expr;
Bitmapset *attnos = list_nth(key_attnos_list, var->varno - 1);
Bitmapset *key_attnos = list_nth(key_attnos_list, var->varno - 1);
/* check if this attribute is from a base table's primary key */
if (bms_is_member(var->varattno - FirstLowInvalidHeapAttributeNumber, attnos))
if (bms_is_member(var->varattno - FirstLowInvalidHeapAttributeNumber, key_attnos))
{
/*
* Remove found key attributes from key_attnos_list, and add this
* to the result list.
*/
bms_del_member(attnos, var->varattno - FirstLowInvalidHeapAttributeNumber);
bms_del_member(key_attnos, var->varattno - FirstLowInvalidHeapAttributeNumber);
keys = bms_add_member(keys, i - FirstLowInvalidHeapAttributeNumber);
}
}
i++;
}
/* Collect relations appearing in the FROM clause */
#if defined(PG_VERSION_NUM) && (PG_VERSION_NUM >= 140000)
rels_in_from = pull_varnos_of_level(&root, (Node *)query->jointree, 0);
#else
rels_in_from = pull_varnos_of_level((Node *)query->jointree, 0);
#endif
/* Collect RTE indexes of relations appearing in the FROM clause */
rels_in_from = get_relids_in_jointree((Node *) query->jointree, false);
/*
* Check if all key attributes of relations in FROM are appearing in the target
* list. If an attribute remains in key_attnos_list in spite of the table is used

View file

@ -1034,6 +1034,54 @@ drop cascades to table ivm_rls2
DROP TABLE num_tbl CASCADE;
DROP USER ivm_user;
DROP USER ivm_admin;
-- automatic index creation
BEGIN;
CREATE TABLE base_a (i int primary key, j int);
CREATE TABLE base_b (i int primary key, j int);
--- group by: create an index
SELECT create_immv('mv_idx1', 'SELECT i, sum(j) FROM base_a GROUP BY i');
NOTICE: created index "mv_idx1_index" on immv "mv_idx1"
create_immv
-------------
0
(1 row)
--- distinct: create an index
SELECT create_immv('mv_idx2', 'SELECT DISTINCT j FROM base_a');
NOTICE: created index "mv_idx2_index" on immv "mv_idx2"
create_immv
-------------
0
(1 row)
--- with all pkey columns: create an index
SELECT create_immv('mv_idx3(i_a, i_b)', 'SELECT a.i, b.i FROM base_a a, base_b b');
NOTICE: created index "mv_idx3_index" on immv "mv_idx3"
create_immv
-------------
0
(1 row)
--- missing some pkey columns: no index
SELECT create_immv('mv_idx4', 'SELECT j FROM base_a');
NOTICE: could not create an index on immv "mv_idx4" automatically
DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
HINT: Create an index on the immv for efficient incremental maintenance.
create_immv
-------------
0
(1 row)
SELECT create_immv('mv_idx5', 'SELECT a.i, b.j FROM base_a a, base_b b');
NOTICE: could not create an index on immv "mv_idx5" automatically
DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
HINT: Create an index on the immv for efficient incremental maintenance.
create_immv
-------------
0
(1 row)
ROLLBACK;
-- prevent IMMV chanages
INSERT INTO mv_ivm_1 VALUES(1,1,1);
ERROR: cannot change materialized view "mv_ivm_1"

View file

@ -454,6 +454,25 @@ DROP TABLE num_tbl CASCADE;
DROP USER ivm_user;
DROP USER ivm_admin;
-- automatic index creation
BEGIN;
CREATE TABLE base_a (i int primary key, j int);
CREATE TABLE base_b (i int primary key, j int);
--- group by: create an index
SELECT create_immv('mv_idx1', 'SELECT i, sum(j) FROM base_a GROUP BY i');
--- distinct: create an index
SELECT create_immv('mv_idx2', 'SELECT DISTINCT j FROM base_a');
--- with all pkey columns: create an index
SELECT create_immv('mv_idx3(i_a, i_b)', 'SELECT a.i, b.i FROM base_a a, base_b b');
--- missing some pkey columns: no index
SELECT create_immv('mv_idx4', 'SELECT j FROM base_a');
SELECT create_immv('mv_idx5', 'SELECT a.i, b.j FROM base_a a, base_b b');
ROLLBACK;
-- prevent IMMV chanages
INSERT INTO mv_ivm_1 VALUES(1,1,1);
UPDATE mv_ivm_1 SET k = 1 WHERE i = 1;