In order to re-calculate min/max values for groups where the min or max value is deleted, we need the view query definition in string form. However, pg_get_viewdef cannot be used for this purpose because IMMV's defenition is in pg_ivm_immv but not pg_rewrite. Therefore, we have to convert query definition in pg_ivm_immv to query definition string. We can use pg_get_querydef in PG15, but we cannot in PG14 or earlier, so we use codes in ruleutil.c copied from PG13 or PG14 depending versions.
1010 lines
36 KiB
Text
1010 lines
36 KiB
Text
CREATE EXTENSION pg_ivm;
|
|
GRANT ALL ON SCHEMA public TO public;
|
|
-- create a table to use as a basis for views and materialized views in various combinations
|
|
CREATE TABLE mv_base_a (i int, j int);
|
|
INSERT INTO mv_base_a VALUES
|
|
(1,10),
|
|
(2,20),
|
|
(3,30),
|
|
(4,40),
|
|
(5,50);
|
|
CREATE TABLE mv_base_b (i int, k int);
|
|
INSERT INTO mv_base_b VALUES
|
|
(1,101),
|
|
(2,102),
|
|
(3,103),
|
|
(4,104);
|
|
-- CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_1 AS SELECT i,j,k FROM mv_base_a a INNER JOIN mv_base_b b USING(i) WITH NO DATA;
|
|
SELECT create_immv('mv_ivm_1', 'SELECT i,j,k FROM mv_base_a a INNER JOIN mv_base_b b USING(i)');
|
|
NOTICE: could not create an index on immv "mv_ivm_1" 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
|
|
-------------
|
|
4
|
|
(1 row)
|
|
|
|
SELECT * FROM mv_ivm_1 ORDER BY 1,2,3;
|
|
i | j | k
|
|
---+----+-----
|
|
1 | 10 | 101
|
|
2 | 20 | 102
|
|
3 | 30 | 103
|
|
4 | 40 | 104
|
|
(4 rows)
|
|
|
|
-- immediate maintenance
|
|
BEGIN;
|
|
INSERT INTO mv_base_b VALUES(5,105);
|
|
SELECT * FROM mv_ivm_1 ORDER BY 1,2,3;
|
|
i | j | k
|
|
---+----+-----
|
|
1 | 10 | 101
|
|
2 | 20 | 102
|
|
3 | 30 | 103
|
|
4 | 40 | 104
|
|
5 | 50 | 105
|
|
(5 rows)
|
|
|
|
UPDATE mv_base_a SET j = 0 WHERE i = 1;
|
|
SELECT * FROM mv_ivm_1 ORDER BY 1,2,3;
|
|
i | j | k
|
|
---+----+-----
|
|
1 | 0 | 101
|
|
2 | 20 | 102
|
|
3 | 30 | 103
|
|
4 | 40 | 104
|
|
5 | 50 | 105
|
|
(5 rows)
|
|
|
|
DELETE FROM mv_base_b WHERE (i,k) = (5,105);
|
|
SELECT * FROM mv_ivm_1 ORDER BY 1,2,3;
|
|
i | j | k
|
|
---+----+-----
|
|
1 | 0 | 101
|
|
2 | 20 | 102
|
|
3 | 30 | 103
|
|
4 | 40 | 104
|
|
(4 rows)
|
|
|
|
ROLLBACK;
|
|
SELECT * FROM mv_ivm_1 ORDER BY 1,2,3;
|
|
i | j | k
|
|
---+----+-----
|
|
1 | 10 | 101
|
|
2 | 20 | 102
|
|
3 | 30 | 103
|
|
4 | 40 | 104
|
|
(4 rows)
|
|
|
|
-- TRUNCATE a base table in join views
|
|
BEGIN;
|
|
TRUNCATE mv_base_a;
|
|
SELECT * FROM mv_ivm_1;
|
|
i | j | k
|
|
---+---+---
|
|
(0 rows)
|
|
|
|
ROLLBACK;
|
|
BEGIN;
|
|
TRUNCATE mv_base_b;
|
|
SELECT * FROM mv_ivm_1;
|
|
i | j | k
|
|
---+---+---
|
|
(0 rows)
|
|
|
|
ROLLBACK;
|
|
-- some query syntax
|
|
BEGIN;
|
|
CREATE FUNCTION ivm_func() RETURNS int LANGUAGE 'sql'
|
|
AS 'SELECT 1' IMMUTABLE;
|
|
SELECT create_immv('mv_ivm_func', 'SELECT * FROM ivm_func()');
|
|
NOTICE: could not create an index on immv "mv_ivm_func" 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
|
|
-------------
|
|
1
|
|
(1 row)
|
|
|
|
SELECT create_immv('mv_ivm_no_tbl', 'SELECT 1');
|
|
NOTICE: could not create an index on immv "mv_ivm_no_tbl" 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
|
|
-------------
|
|
1
|
|
(1 row)
|
|
|
|
ROLLBACK;
|
|
-- result of materialized view have DISTINCT clause or the duplicate result.
|
|
BEGIN;
|
|
SELECT create_immv('mv_ivm_duplicate', 'SELECT j FROM mv_base_a');
|
|
NOTICE: could not create an index on immv "mv_ivm_duplicate" 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
|
|
-------------
|
|
5
|
|
(1 row)
|
|
|
|
SELECT create_immv('mv_ivm_distinct', 'SELECT DISTINCT j FROM mv_base_a');
|
|
NOTICE: created index "mv_ivm_distinct_index" on immv "mv_ivm_distinct"
|
|
create_immv
|
|
-------------
|
|
5
|
|
(1 row)
|
|
|
|
INSERT INTO mv_base_a VALUES(6,20);
|
|
SELECT * FROM mv_ivm_duplicate ORDER BY 1;
|
|
j
|
|
----
|
|
10
|
|
20
|
|
20
|
|
30
|
|
40
|
|
50
|
|
(6 rows)
|
|
|
|
SELECT * FROM mv_ivm_distinct ORDER BY 1;
|
|
j | __ivm_count__
|
|
----+---------------
|
|
10 | 1
|
|
20 | 2
|
|
30 | 1
|
|
40 | 1
|
|
50 | 1
|
|
(5 rows)
|
|
|
|
DELETE FROM mv_base_a WHERE (i,j) = (2,20);
|
|
SELECT * FROM mv_ivm_duplicate ORDER BY 1;
|
|
j
|
|
----
|
|
10
|
|
20
|
|
30
|
|
40
|
|
50
|
|
(5 rows)
|
|
|
|
SELECT * FROM mv_ivm_distinct ORDER BY 1;
|
|
j | __ivm_count__
|
|
----+---------------
|
|
10 | 1
|
|
20 | 1
|
|
30 | 1
|
|
40 | 1
|
|
50 | 1
|
|
(5 rows)
|
|
|
|
ROLLBACK;
|
|
-- support SUM(), COUNT() and AVG() aggregate functions
|
|
BEGIN;
|
|
SELECT create_immv('mv_ivm_agg', 'SELECT i, SUM(j), COUNT(i), AVG(j) FROM mv_base_a GROUP BY i');
|
|
NOTICE: created index "mv_ivm_agg_index" on immv "mv_ivm_agg"
|
|
create_immv
|
|
-------------
|
|
5
|
|
(1 row)
|
|
|
|
SELECT * FROM mv_ivm_agg ORDER BY 1,2,3,4;
|
|
i | sum | count | avg | __ivm_count_sum__ | __ivm_count_avg__ | __ivm_sum_avg__ | __ivm_count__
|
|
---+-----+-------+---------------------+-------------------+-------------------+-----------------+---------------
|
|
1 | 10 | 1 | 10.0000000000000000 | 1 | 1 | 10 | 1
|
|
2 | 20 | 1 | 20.0000000000000000 | 1 | 1 | 20 | 1
|
|
3 | 30 | 1 | 30.0000000000000000 | 1 | 1 | 30 | 1
|
|
4 | 40 | 1 | 40.0000000000000000 | 1 | 1 | 40 | 1
|
|
5 | 50 | 1 | 50.0000000000000000 | 1 | 1 | 50 | 1
|
|
(5 rows)
|
|
|
|
INSERT INTO mv_base_a VALUES(2,100);
|
|
SELECT * FROM mv_ivm_agg ORDER BY 1,2,3,4;
|
|
i | sum | count | avg | __ivm_count_sum__ | __ivm_count_avg__ | __ivm_sum_avg__ | __ivm_count__
|
|
---+-----+-------+---------------------+-------------------+-------------------+-----------------+---------------
|
|
1 | 10 | 1 | 10.0000000000000000 | 1 | 1 | 10 | 1
|
|
2 | 120 | 2 | 60.0000000000000000 | 2 | 2 | 120 | 2
|
|
3 | 30 | 1 | 30.0000000000000000 | 1 | 1 | 30 | 1
|
|
4 | 40 | 1 | 40.0000000000000000 | 1 | 1 | 40 | 1
|
|
5 | 50 | 1 | 50.0000000000000000 | 1 | 1 | 50 | 1
|
|
(5 rows)
|
|
|
|
UPDATE mv_base_a SET j = 200 WHERE (i,j) = (2,100);
|
|
SELECT * FROM mv_ivm_agg ORDER BY 1,2,3,4;
|
|
i | sum | count | avg | __ivm_count_sum__ | __ivm_count_avg__ | __ivm_sum_avg__ | __ivm_count__
|
|
---+-----+-------+----------------------+-------------------+-------------------+-----------------+---------------
|
|
1 | 10 | 1 | 10.0000000000000000 | 1 | 1 | 10 | 1
|
|
2 | 220 | 2 | 110.0000000000000000 | 2 | 2 | 220 | 2
|
|
3 | 30 | 1 | 30.0000000000000000 | 1 | 1 | 30 | 1
|
|
4 | 40 | 1 | 40.0000000000000000 | 1 | 1 | 40 | 1
|
|
5 | 50 | 1 | 50.0000000000000000 | 1 | 1 | 50 | 1
|
|
(5 rows)
|
|
|
|
DELETE FROM mv_base_a WHERE (i,j) = (2,200);
|
|
SELECT * FROM mv_ivm_agg ORDER BY 1,2,3,4;
|
|
i | sum | count | avg | __ivm_count_sum__ | __ivm_count_avg__ | __ivm_sum_avg__ | __ivm_count__
|
|
---+-----+-------+---------------------+-------------------+-------------------+-----------------+---------------
|
|
1 | 10 | 1 | 10.0000000000000000 | 1 | 1 | 10 | 1
|
|
2 | 20 | 1 | 20.0000000000000000 | 1 | 1 | 20 | 1
|
|
3 | 30 | 1 | 30.0000000000000000 | 1 | 1 | 30 | 1
|
|
4 | 40 | 1 | 40.0000000000000000 | 1 | 1 | 40 | 1
|
|
5 | 50 | 1 | 50.0000000000000000 | 1 | 1 | 50 | 1
|
|
(5 rows)
|
|
|
|
ROLLBACK;
|
|
-- support COUNT(*) aggregate function
|
|
BEGIN;
|
|
SELECT create_immv('mv_ivm_agg', 'SELECT i, SUM(j), COUNT(*) FROM mv_base_a GROUP BY i');
|
|
NOTICE: created index "mv_ivm_agg_index" on immv "mv_ivm_agg"
|
|
create_immv
|
|
-------------
|
|
5
|
|
(1 row)
|
|
|
|
SELECT * FROM mv_ivm_agg ORDER BY 1,2,3;
|
|
i | sum | count | __ivm_count_sum__ | __ivm_count__
|
|
---+-----+-------+-------------------+---------------
|
|
1 | 10 | 1 | 1 | 1
|
|
2 | 20 | 1 | 1 | 1
|
|
3 | 30 | 1 | 1 | 1
|
|
4 | 40 | 1 | 1 | 1
|
|
5 | 50 | 1 | 1 | 1
|
|
(5 rows)
|
|
|
|
INSERT INTO mv_base_a VALUES(2,100);
|
|
SELECT * FROM mv_ivm_agg ORDER BY 1,2,3;
|
|
i | sum | count | __ivm_count_sum__ | __ivm_count__
|
|
---+-----+-------+-------------------+---------------
|
|
1 | 10 | 1 | 1 | 1
|
|
2 | 120 | 2 | 2 | 2
|
|
3 | 30 | 1 | 1 | 1
|
|
4 | 40 | 1 | 1 | 1
|
|
5 | 50 | 1 | 1 | 1
|
|
(5 rows)
|
|
|
|
ROLLBACK;
|
|
-- TRUNCATE a base table in aggregate views
|
|
BEGIN;
|
|
SELECT create_immv('mv_ivm_agg', 'SELECT i, SUM(j), COUNT(*) FROM mv_base_a GROUP BY i');
|
|
NOTICE: created index "mv_ivm_agg_index" on immv "mv_ivm_agg"
|
|
create_immv
|
|
-------------
|
|
5
|
|
(1 row)
|
|
|
|
TRUNCATE mv_base_a;
|
|
SELECT sum, count FROM mv_ivm_agg;
|
|
sum | count
|
|
-----+-------
|
|
(0 rows)
|
|
|
|
SELECT i, SUM(j), COUNT(*) FROM mv_base_a GROUP BY i;
|
|
i | sum | count
|
|
---+-----+-------
|
|
(0 rows)
|
|
|
|
ROLLBACK;
|
|
-- support aggregate functions without GROUP clause
|
|
BEGIN;
|
|
SELECT create_immv('mv_ivm_group', 'SELECT SUM(j), COUNT(j), AVG(j) FROM mv_base_a');
|
|
NOTICE: could not create an index on immv "mv_ivm_group" 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
|
|
-------------
|
|
1
|
|
(1 row)
|
|
|
|
SELECT * FROM mv_ivm_group ORDER BY 1;
|
|
sum | count | avg | __ivm_count_sum__ | __ivm_count_avg__ | __ivm_sum_avg__ | __ivm_count__
|
|
-----+-------+---------------------+-------------------+-------------------+-----------------+---------------
|
|
150 | 5 | 30.0000000000000000 | 5 | 5 | 150 | 5
|
|
(1 row)
|
|
|
|
INSERT INTO mv_base_a VALUES(6,60);
|
|
SELECT * FROM mv_ivm_group ORDER BY 1;
|
|
sum | count | avg | __ivm_count_sum__ | __ivm_count_avg__ | __ivm_sum_avg__ | __ivm_count__
|
|
-----+-------+---------------------+-------------------+-------------------+-----------------+---------------
|
|
210 | 6 | 35.0000000000000000 | 6 | 6 | 210 | 6
|
|
(1 row)
|
|
|
|
DELETE FROM mv_base_a;
|
|
SELECT * FROM mv_ivm_group ORDER BY 1;
|
|
sum | count | avg | __ivm_count_sum__ | __ivm_count_avg__ | __ivm_sum_avg__ | __ivm_count__
|
|
-----+-------+-----+-------------------+-------------------+-----------------+---------------
|
|
| 0 | | 0 | 0 | | 0
|
|
(1 row)
|
|
|
|
ROLLBACK;
|
|
-- TRUNCATE a base table in aggregate views without GROUP clause
|
|
BEGIN;
|
|
SELECT create_immv('mv_ivm_group', 'SELECT SUM(j), COUNT(j), AVG(j) FROM mv_base_a');
|
|
NOTICE: could not create an index on immv "mv_ivm_group" 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
|
|
-------------
|
|
1
|
|
(1 row)
|
|
|
|
TRUNCATE mv_base_a;
|
|
SELECT sum, count, avg FROM mv_ivm_group;
|
|
sum | count | avg
|
|
-----+-------+-----
|
|
| 0 |
|
|
(1 row)
|
|
|
|
SELECT SUM(j), COUNT(j), AVG(j) FROM mv_base_a;
|
|
sum | count | avg
|
|
-----+-------+-----
|
|
| 0 |
|
|
(1 row)
|
|
|
|
ROLLBACK;
|
|
-- resolved issue: When use AVG() function and values is indivisible, result of AVG() is incorrect.
|
|
BEGIN;
|
|
SELECT create_immv('mv_ivm_avg_bug', 'SELECT i, SUM(j), COUNT(j), AVG(j) FROM mv_base_A GROUP BY i');
|
|
NOTICE: created index "mv_ivm_avg_bug_index" on immv "mv_ivm_avg_bug"
|
|
create_immv
|
|
-------------
|
|
5
|
|
(1 row)
|
|
|
|
SELECT * FROM mv_ivm_avg_bug ORDER BY 1,2,3;
|
|
i | sum | count | avg | __ivm_count_sum__ | __ivm_count_avg__ | __ivm_sum_avg__ | __ivm_count__
|
|
---+-----+-------+---------------------+-------------------+-------------------+-----------------+---------------
|
|
1 | 10 | 1 | 10.0000000000000000 | 1 | 1 | 10 | 1
|
|
2 | 20 | 1 | 20.0000000000000000 | 1 | 1 | 20 | 1
|
|
3 | 30 | 1 | 30.0000000000000000 | 1 | 1 | 30 | 1
|
|
4 | 40 | 1 | 40.0000000000000000 | 1 | 1 | 40 | 1
|
|
5 | 50 | 1 | 50.0000000000000000 | 1 | 1 | 50 | 1
|
|
(5 rows)
|
|
|
|
INSERT INTO mv_base_a VALUES
|
|
(1,0),
|
|
(1,0),
|
|
(2,30),
|
|
(2,30);
|
|
SELECT * FROM mv_ivm_avg_bug ORDER BY 1,2,3;
|
|
i | sum | count | avg | __ivm_count_sum__ | __ivm_count_avg__ | __ivm_sum_avg__ | __ivm_count__
|
|
---+-----+-------+---------------------+-------------------+-------------------+-----------------+---------------
|
|
1 | 10 | 3 | 3.3333333333333333 | 3 | 3 | 10 | 3
|
|
2 | 80 | 3 | 26.6666666666666667 | 3 | 3 | 80 | 3
|
|
3 | 30 | 1 | 30.0000000000000000 | 1 | 1 | 30 | 1
|
|
4 | 40 | 1 | 40.0000000000000000 | 1 | 1 | 40 | 1
|
|
5 | 50 | 1 | 50.0000000000000000 | 1 | 1 | 50 | 1
|
|
(5 rows)
|
|
|
|
DELETE FROM mv_base_a WHERE (i,j) = (1,0);
|
|
DELETE FROM mv_base_a WHERE (i,j) = (2,30);
|
|
SELECT * FROM mv_ivm_avg_bug ORDER BY 1,2,3;
|
|
i | sum | count | avg | __ivm_count_sum__ | __ivm_count_avg__ | __ivm_sum_avg__ | __ivm_count__
|
|
---+-----+-------+---------------------+-------------------+-------------------+-----------------+---------------
|
|
1 | 10 | 1 | 10.0000000000000000 | 1 | 1 | 10 | 1
|
|
2 | 20 | 1 | 20.0000000000000000 | 1 | 1 | 20 | 1
|
|
3 | 30 | 1 | 30.0000000000000000 | 1 | 1 | 30 | 1
|
|
4 | 40 | 1 | 40.0000000000000000 | 1 | 1 | 40 | 1
|
|
5 | 50 | 1 | 50.0000000000000000 | 1 | 1 | 50 | 1
|
|
(5 rows)
|
|
|
|
ROLLBACK;
|
|
-- support MIN(), MAX() aggregate functions
|
|
BEGIN;
|
|
SELECT create_immv('mv_ivm_min_max', 'SELECT i, MIN(j), MAX(j) FROM mv_base_a GROUP BY i');
|
|
NOTICE: created index "mv_ivm_min_max_index" on immv "mv_ivm_min_max"
|
|
create_immv
|
|
-------------
|
|
5
|
|
(1 row)
|
|
|
|
SELECT * FROM mv_ivm_min_max ORDER BY 1,2,3;
|
|
i | min | max | __ivm_count_min__ | __ivm_count_max__ | __ivm_count__
|
|
---+-----+-----+-------------------+-------------------+---------------
|
|
1 | 10 | 10 | 1 | 1 | 1
|
|
2 | 20 | 20 | 1 | 1 | 1
|
|
3 | 30 | 30 | 1 | 1 | 1
|
|
4 | 40 | 40 | 1 | 1 | 1
|
|
5 | 50 | 50 | 1 | 1 | 1
|
|
(5 rows)
|
|
|
|
INSERT INTO mv_base_a VALUES
|
|
(1,11), (1,12),
|
|
(2,21), (2,22),
|
|
(3,31), (3,32),
|
|
(4,41), (4,42),
|
|
(5,51), (5,52);
|
|
SELECT * FROM mv_ivm_min_max ORDER BY 1,2,3;
|
|
i | min | max | __ivm_count_min__ | __ivm_count_max__ | __ivm_count__
|
|
---+-----+-----+-------------------+-------------------+---------------
|
|
1 | 10 | 12 | 3 | 3 | 3
|
|
2 | 20 | 22 | 3 | 3 | 3
|
|
3 | 30 | 32 | 3 | 3 | 3
|
|
4 | 40 | 42 | 3 | 3 | 3
|
|
5 | 50 | 52 | 3 | 3 | 3
|
|
(5 rows)
|
|
|
|
DELETE FROM mv_base_a WHERE (i,j) IN ((1,10), (2,21), (3,32));
|
|
SELECT * FROM mv_ivm_min_max ORDER BY 1,2,3;
|
|
i | min | max | __ivm_count_min__ | __ivm_count_max__ | __ivm_count__
|
|
---+-----+-----+-------------------+-------------------+---------------
|
|
1 | 11 | 12 | 2 | 2 | 2
|
|
2 | 20 | 22 | 2 | 2 | 2
|
|
3 | 30 | 31 | 2 | 2 | 2
|
|
4 | 40 | 42 | 3 | 3 | 3
|
|
5 | 50 | 52 | 3 | 3 | 3
|
|
(5 rows)
|
|
|
|
ROLLBACK;
|
|
-- support MIN(), MAX() aggregate functions without GROUP clause
|
|
BEGIN;
|
|
SELECT create_immv('mv_ivm_min_max', 'SELECT MIN(j), MAX(j) FROM mv_base_a');
|
|
NOTICE: could not create an index on immv "mv_ivm_min_max" 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
|
|
-------------
|
|
1
|
|
(1 row)
|
|
|
|
SELECT * FROM mv_ivm_min_max;
|
|
min | max | __ivm_count_min__ | __ivm_count_max__ | __ivm_count__
|
|
-----+-----+-------------------+-------------------+---------------
|
|
10 | 50 | 5 | 5 | 5
|
|
(1 row)
|
|
|
|
INSERT INTO mv_base_a VALUES
|
|
(0,0), (6,60), (7,70);
|
|
SELECT * FROM mv_ivm_min_max;
|
|
min | max | __ivm_count_min__ | __ivm_count_max__ | __ivm_count__
|
|
-----+-----+-------------------+-------------------+---------------
|
|
0 | 70 | 8 | 8 | 8
|
|
(1 row)
|
|
|
|
DELETE FROM mv_base_a WHERE (i,j) IN ((0,0), (7,70));
|
|
SELECT * FROM mv_ivm_min_max;
|
|
min | max | __ivm_count_min__ | __ivm_count_max__ | __ivm_count__
|
|
-----+-----+-------------------+-------------------+---------------
|
|
10 | 60 | 6 | 6 | 6
|
|
(1 row)
|
|
|
|
DELETE FROM mv_base_a;
|
|
SELECT * FROM mv_ivm_min_max;
|
|
min | max | __ivm_count_min__ | __ivm_count_max__ | __ivm_count__
|
|
-----+-----+-------------------+-------------------+---------------
|
|
| | 0 | 0 | 0
|
|
(1 row)
|
|
|
|
ROLLBACK;
|
|
-- support subquery in FROM clause
|
|
BEGIN;
|
|
SELECT create_immv('mv_ivm_subquery01', 'SELECT a.i,a.j FROM mv_base_a a, (SELECT * FROM mv_base_b) b WHERE a.i = b.i');
|
|
NOTICE: could not create an index on immv "mv_ivm_subquery01" 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
|
|
-------------
|
|
4
|
|
(1 row)
|
|
|
|
SELECT * FROM mv_ivm_subquery01 ORDER BY 1,2;
|
|
i | j
|
|
---+----
|
|
1 | 10
|
|
2 | 20
|
|
3 | 30
|
|
4 | 40
|
|
(4 rows)
|
|
|
|
INSERT INTO mv_base_b VALUES(5,105);
|
|
SELECT * FROM mv_ivm_subquery01 ORDER BY 1,2;
|
|
i | j
|
|
---+----
|
|
1 | 10
|
|
2 | 20
|
|
3 | 30
|
|
4 | 40
|
|
5 | 50
|
|
(5 rows)
|
|
|
|
UPDATE mv_base_a SET j = 0 WHERE i = 1;
|
|
SELECT * FROM mv_ivm_subquery01 ORDER BY 1,2;
|
|
i | j
|
|
---+----
|
|
1 | 0
|
|
2 | 20
|
|
3 | 30
|
|
4 | 40
|
|
5 | 50
|
|
(5 rows)
|
|
|
|
DELETE FROM mv_base_b WHERE (i,k) = (5,105);
|
|
SELECT * FROM mv_ivm_subquery01 ORDER BY 1,2;
|
|
i | j
|
|
---+----
|
|
1 | 0
|
|
2 | 20
|
|
3 | 30
|
|
4 | 40
|
|
(4 rows)
|
|
|
|
ROLLBACK;
|
|
-- support self join view and multiple change on the same table
|
|
BEGIN;
|
|
CREATE TABLE base_t (i int, v int);
|
|
INSERT INTO base_t VALUES (1, 10), (2, 20), (3, 30);
|
|
SELECT create_immv('mv_self(v1, v2)',
|
|
'SELECT t1.v, t2.v FROM base_t AS t1 JOIN base_t AS t2 ON t1.i = t2.i');
|
|
NOTICE: could not create an index on immv "mv_self" 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
|
|
-------------
|
|
3
|
|
(1 row)
|
|
|
|
SELECT * FROM mv_self ORDER BY v1;
|
|
v1 | v2
|
|
----+----
|
|
10 | 10
|
|
20 | 20
|
|
30 | 30
|
|
(3 rows)
|
|
|
|
INSERT INTO base_t VALUES (4,40);
|
|
DELETE FROM base_t WHERE i = 1;
|
|
UPDATE base_t SET v = v*10 WHERE i=2;
|
|
SELECT * FROM mv_self ORDER BY v1;
|
|
v1 | v2
|
|
-----+-----
|
|
30 | 30
|
|
40 | 40
|
|
200 | 200
|
|
(3 rows)
|
|
|
|
WITH
|
|
ins_t1 AS (INSERT INTO base_t VALUES (5,50) RETURNING 1),
|
|
ins_t2 AS (INSERT INTO base_t VALUES (6,60) RETURNING 1),
|
|
upd_t AS (UPDATE base_t SET v = v + 100 RETURNING 1),
|
|
dlt_t AS (DELETE FROM base_t WHERE i IN (4,5) RETURNING 1)
|
|
SELECT NULL;
|
|
?column?
|
|
----------
|
|
|
|
(1 row)
|
|
|
|
SELECT * FROM mv_self ORDER BY v1;
|
|
v1 | v2
|
|
-----+-----
|
|
50 | 50
|
|
60 | 60
|
|
130 | 130
|
|
300 | 300
|
|
(4 rows)
|
|
|
|
ROLLBACK;
|
|
-- support simultaneous table changes
|
|
BEGIN;
|
|
CREATE TABLE base_r (i int, v int);
|
|
CREATE TABLE base_s (i int, v int);
|
|
INSERT INTO base_r VALUES (1, 10), (2, 20), (3, 30);
|
|
INSERT INTO base_s VALUES (1, 100), (2, 200), (3, 300);
|
|
SELECT create_immv('mv(v1, v2)', 'SELECT r.v, s.v FROM base_r AS r JOIN base_s AS s USING(i)');;
|
|
NOTICE: could not create an index on immv "mv" 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
|
|
-------------
|
|
3
|
|
(1 row)
|
|
|
|
SELECT * FROM mv ORDER BY v1;
|
|
v1 | v2
|
|
----+-----
|
|
10 | 100
|
|
20 | 200
|
|
30 | 300
|
|
(3 rows)
|
|
|
|
WITH
|
|
ins_r AS (INSERT INTO base_r VALUES (1,11) RETURNING 1),
|
|
ins_r2 AS (INSERT INTO base_r VALUES (3,33) RETURNING 1),
|
|
ins_s AS (INSERT INTO base_s VALUES (2,222) RETURNING 1),
|
|
upd_r AS (UPDATE base_r SET v = v + 1000 WHERE i = 2 RETURNING 1),
|
|
dlt_s AS (DELETE FROM base_s WHERE i = 3 RETURNING 1)
|
|
SELECT NULL;
|
|
?column?
|
|
----------
|
|
|
|
(1 row)
|
|
|
|
SELECT * FROM mv ORDER BY v1;
|
|
v1 | v2
|
|
------+-----
|
|
10 | 100
|
|
11 | 100
|
|
1020 | 200
|
|
1020 | 222
|
|
(4 rows)
|
|
|
|
-- support foreign reference constraints
|
|
BEGIN;
|
|
WARNING: there is already a transaction in progress
|
|
CREATE TABLE ri1 (i int PRIMARY KEY);
|
|
CREATE TABLE ri2 (i int PRIMARY KEY REFERENCES ri1(i) ON UPDATE CASCADE ON DELETE CASCADE, v int);
|
|
INSERT INTO ri1 VALUES (1),(2),(3);
|
|
INSERT INTO ri2 VALUES (1),(2),(3);
|
|
SELECT create_immv('mv_ri(i1, i2)', 'SELECT ri1.i, ri2.i FROM ri1 JOIN ri2 USING(i)');
|
|
NOTICE: created index "mv_ri_index" on immv "mv_ri"
|
|
create_immv
|
|
-------------
|
|
3
|
|
(1 row)
|
|
|
|
SELECT * FROM mv_ri ORDER BY i1;
|
|
i1 | i2
|
|
----+----
|
|
1 | 1
|
|
2 | 2
|
|
3 | 3
|
|
(3 rows)
|
|
|
|
UPDATE ri1 SET i=10 where i=1;
|
|
DELETE FROM ri1 WHERE i=2;
|
|
SELECT * FROM mv_ri ORDER BY i2;
|
|
i1 | i2
|
|
----+----
|
|
3 | 3
|
|
10 | 10
|
|
(2 rows)
|
|
|
|
ROLLBACK;
|
|
-- views including NULL
|
|
BEGIN;
|
|
CREATE TABLE base_t (i int, v int);
|
|
INSERT INTO base_t VALUES (1,10),(2, NULL);
|
|
SELECT create_immv('mv', 'SELECT * FROM base_t');
|
|
NOTICE: could not create an index on immv "mv" 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
|
|
-------------
|
|
2
|
|
(1 row)
|
|
|
|
SELECT * FROM mv ORDER BY i;
|
|
i | v
|
|
---+----
|
|
1 | 10
|
|
2 |
|
|
(2 rows)
|
|
|
|
UPDATE base_t SET v = 20 WHERE i = 2;
|
|
SELECT * FROM mv ORDER BY i;
|
|
i | v
|
|
---+----
|
|
1 | 10
|
|
2 | 20
|
|
(2 rows)
|
|
|
|
ROLLBACK;
|
|
BEGIN;
|
|
CREATE TABLE base_t (i int);
|
|
SELECT create_immv('mv', 'SELECT * FROM base_t');
|
|
NOTICE: could not create an index on immv "mv" 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 * FROM mv ORDER BY i;
|
|
i
|
|
---
|
|
(0 rows)
|
|
|
|
INSERT INTO base_t VALUES (1),(NULL);
|
|
SELECT * FROM mv ORDER BY i;
|
|
i
|
|
---
|
|
1
|
|
|
|
(2 rows)
|
|
|
|
ROLLBACK;
|
|
BEGIN;
|
|
CREATE TABLE base_t (i int, v int);
|
|
INSERT INTO base_t VALUES (NULL, 1), (NULL, 2), (1, 10), (1, 20);
|
|
SELECT create_immv('mv', 'SELECT i, sum(v) FROM base_t GROUP BY i');
|
|
NOTICE: created index "mv_index" on immv "mv"
|
|
create_immv
|
|
-------------
|
|
2
|
|
(1 row)
|
|
|
|
SELECT * FROM mv ORDER BY i;
|
|
i | sum | __ivm_count_sum__ | __ivm_count__
|
|
---+-----+-------------------+---------------
|
|
1 | 30 | 2 | 2
|
|
| 3 | 2 | 2
|
|
(2 rows)
|
|
|
|
UPDATE base_t SET v = v * 10;
|
|
SELECT * FROM mv ORDER BY i;
|
|
i | sum | __ivm_count_sum__ | __ivm_count__
|
|
---+-----+-------------------+---------------
|
|
1 | 300 | 2 | 2
|
|
| 30 | 2 | 2
|
|
(2 rows)
|
|
|
|
ROLLBACK;
|
|
BEGIN;
|
|
CREATE TABLE base_t (i int, v int);
|
|
INSERT INTO base_t VALUES (NULL, 1), (NULL, 2), (NULL, 3), (NULL, 4), (NULL, 5);
|
|
SELECT create_immv('mv', 'SELECT i, min(v), max(v) FROM base_t GROUP BY i');
|
|
NOTICE: created index "mv_index" on immv "mv"
|
|
create_immv
|
|
-------------
|
|
1
|
|
(1 row)
|
|
|
|
SELECT * FROM mv ORDER BY i;
|
|
i | min | max | __ivm_count_min__ | __ivm_count_max__ | __ivm_count__
|
|
---+-----+-----+-------------------+-------------------+---------------
|
|
| 1 | 5 | 5 | 5 | 5
|
|
(1 row)
|
|
|
|
DELETE FROM base_t WHERE v = 1;
|
|
SELECT * FROM mv ORDER BY i;
|
|
i | min | max | __ivm_count_min__ | __ivm_count_max__ | __ivm_count__
|
|
---+-----+-----+-------------------+-------------------+---------------
|
|
| 2 | 5 | 4 | 4 | 4
|
|
(1 row)
|
|
|
|
DELETE FROM base_t WHERE v = 3;
|
|
SELECT * FROM mv ORDER BY i;
|
|
i | min | max | __ivm_count_min__ | __ivm_count_max__ | __ivm_count__
|
|
---+-----+-----+-------------------+-------------------+---------------
|
|
| 2 | 5 | 3 | 3 | 3
|
|
(1 row)
|
|
|
|
DELETE FROM base_t WHERE v = 5;
|
|
SELECT * FROM mv ORDER BY i;
|
|
i | min | max | __ivm_count_min__ | __ivm_count_max__ | __ivm_count__
|
|
---+-----+-----+-------------------+-------------------+---------------
|
|
| 2 | 4 | 2 | 2 | 2
|
|
(1 row)
|
|
|
|
ROLLBACK;
|
|
-- IMMV containing user defined type
|
|
BEGIN;
|
|
CREATE TYPE mytype;
|
|
CREATE FUNCTION mytype_in(cstring)
|
|
RETURNS mytype AS 'int4in'
|
|
LANGUAGE INTERNAL STRICT IMMUTABLE;
|
|
NOTICE: return type mytype is only a shell
|
|
CREATE FUNCTION mytype_out(mytype)
|
|
RETURNS cstring AS 'int4out'
|
|
LANGUAGE INTERNAL STRICT IMMUTABLE;
|
|
NOTICE: argument type mytype is only a shell
|
|
CREATE TYPE mytype (
|
|
LIKE = int4,
|
|
INPUT = mytype_in,
|
|
OUTPUT = mytype_out
|
|
);
|
|
CREATE FUNCTION mytype_eq(mytype, mytype)
|
|
RETURNS bool AS 'int4eq'
|
|
LANGUAGE INTERNAL STRICT IMMUTABLE;
|
|
CREATE FUNCTION mytype_lt(mytype, mytype)
|
|
RETURNS bool AS 'int4lt'
|
|
LANGUAGE INTERNAL STRICT IMMUTABLE;
|
|
CREATE FUNCTION mytype_cmp(mytype, mytype)
|
|
RETURNS integer AS 'btint4cmp'
|
|
LANGUAGE INTERNAL STRICT IMMUTABLE;
|
|
CREATE OPERATOR = (
|
|
leftarg = mytype, rightarg = mytype,
|
|
procedure = mytype_eq);
|
|
CREATE OPERATOR < (
|
|
leftarg = mytype, rightarg = mytype,
|
|
procedure = mytype_lt);
|
|
CREATE OPERATOR CLASS mytype_ops
|
|
DEFAULT FOR TYPE mytype USING btree AS
|
|
OPERATOR 1 <,
|
|
OPERATOR 3 = ,
|
|
FUNCTION 1 mytype_cmp(mytype,mytype);
|
|
CREATE TABLE t_mytype (x mytype);
|
|
SELECT create_immv('mv_mytype',
|
|
'SELECT * FROM t_mytype');
|
|
NOTICE: could not create an index on immv "mv_mytype" 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)
|
|
|
|
INSERT INTO t_mytype VALUES ('1'::mytype);
|
|
SELECT * FROM mv_mytype;
|
|
x
|
|
---
|
|
1
|
|
(1 row)
|
|
|
|
ROLLBACK;
|
|
-- outer join is not supported
|
|
SELECT create_immv('mv(a,b)',
|
|
'SELECT a.i, b.i FROM mv_base_a a LEFT JOIN mv_base_b b ON a.i=b.i');
|
|
ERROR: OUTER JOIN is not supported on incrementally maintainable materialized view
|
|
-- CTE is not supported
|
|
SELECT create_immv('mv',
|
|
'WITH b AS ( SELECT * FROM mv_base_b) SELECT a.i,a.j FROM mv_base_a a, b WHERE a.i = b.i;');
|
|
ERROR: CTE is not supported on incrementally maintainable materialized view
|
|
-- contain system column
|
|
SELECT create_immv('mv_ivm01', 'SELECT i,j,xmin FROM mv_base_a');
|
|
ERROR: system column is not supported on incrementally maintainable materialized view
|
|
SELECT create_immv('mv_ivm02', 'SELECT i,j FROM mv_base_a WHERE xmin = ''610''');
|
|
ERROR: system column is not supported on incrementally maintainable materialized view
|
|
SELECT create_immv('mv_ivm03', 'SELECT i,j,xmin::text AS x_min FROM mv_base_a');
|
|
ERROR: system column is not supported on incrementally maintainable materialized view
|
|
SELECT create_immv('mv_ivm04', 'SELECT i,j,xidsend(xmin) AS x_min FROM mv_base_a');
|
|
ERROR: system column is not supported on incrementally maintainable materialized view
|
|
-- contain subquery
|
|
SELECT create_immv('mv_ivm03', 'SELECT i,j FROM mv_base_a WHERE i IN (SELECT i FROM mv_base_b WHERE k < 103 )');
|
|
ERROR: this query is not allowed on incrementally maintainable materialized view
|
|
HINT: Only simple subquery is supported
|
|
SELECT create_immv('mv_ivm04', 'SELECT a.i,a.j FROM mv_base_a a, (SELECT DISTINCT i FROM mv_base_b) b WHERE a.i = b.i');
|
|
ERROR: DISTINCT clause in nested query are not supported on incrementally maintainable materialized view
|
|
SELECT create_immv('mv_ivm05', 'SELECT i,j, (SELECT k FROM mv_base_b b WHERE a.i = b.i) FROM mv_base_a a');
|
|
ERROR: this query is not allowed on incrementally maintainable materialized view
|
|
HINT: subquery is not supported in targetlist
|
|
-- contain ORDER BY
|
|
SELECT create_immv('mv_ivm07', 'SELECT i,j,k FROM mv_base_a a INNER JOIN mv_base_b b USING(i) ORDER BY i,j,k');
|
|
ERROR: ORDER BY clause is not supported on incrementally maintainable materialized view
|
|
-- contain HAVING
|
|
SELECT create_immv('mv_ivm08', 'SELECT i,j,k FROM mv_base_a a INNER JOIN mv_base_b b USING(i) GROUP BY i,j,k HAVING SUM(i) > 5');
|
|
ERROR: HAVING clause is not supported on incrementally maintainable materialized view
|
|
-- contain GROUP BY without aggregate
|
|
SELECT create_immv('mv_ivm08', 'SELECT i,j FROM mv_base_a GROUP BY i,j');
|
|
ERROR: GROUP BY clause without aggregate is not supported on incrementally maintainable materialized view
|
|
-- contain view or materialized view
|
|
CREATE VIEW b_view AS SELECT i,k FROM mv_base_b;
|
|
CREATE MATERIALIZED VIEW b_mview AS SELECT i,k FROM mv_base_b;
|
|
SELECT create_immv('mv_ivm07', 'SELECT a.i,a.j FROM mv_base_a a,b_view b WHERE a.i = b.i');
|
|
ERROR: VIEW or MATERIALIZED VIEW is not supported on incrementally maintainable materialized view
|
|
SELECT create_immv('mv_ivm08', 'SELECT a.i,a.j FROM mv_base_a a,b_mview b WHERE a.i = b.i');
|
|
ERROR: VIEW or MATERIALIZED VIEW is not supported on incrementally maintainable materialized view
|
|
SELECT create_immv('mv_ivm09', 'SELECT a.i,a.j FROM mv_base_a a, (SELECT i, COUNT(*) FROM mv_base_b GROUP BY i) b WHERE a.i = b.i');
|
|
ERROR: aggregate functions in nested query are not supported on incrementally maintainable materialized view
|
|
-- contain mutable functions
|
|
SELECT create_immv('mv_ivm12', 'SELECT i,j FROM mv_base_a WHERE i = random()::int');
|
|
ERROR: mutable function is not supported on incrementally maintainable materialized view
|
|
HINT: functions must be marked IMMUTABLE
|
|
-- LIMIT/OFFSET is not supported
|
|
SELECT create_immv('mv_ivm13', 'SELECT i,j FROM mv_base_a LIMIT 10 OFFSET 5');
|
|
ERROR: LIMIT/OFFSET clause is not supported on incrementally maintainable materialized view
|
|
-- DISTINCT ON is not supported
|
|
SELECT create_immv('mv_ivm14', 'SELECT DISTINCT ON(i) i, j FROM mv_base_a');
|
|
ERROR: DISTINCT ON is not supported on incrementally maintainable materialized view
|
|
-- TABLESAMPLE clause is not supported
|
|
SELECT create_immv('mv_ivm15', 'SELECT i, j FROM mv_base_a TABLESAMPLE SYSTEM(50)');
|
|
ERROR: TABLESAMPLE clause is not supported on incrementally maintainable materialized view
|
|
-- window functions are not supported
|
|
SELECT create_immv('mv_ivm16', 'SELECT *, cume_dist() OVER (ORDER BY i) AS rank FROM mv_base_a');
|
|
ERROR: window functions are not supported on incrementally maintainable materialized view
|
|
-- inheritance parent is not supported
|
|
BEGIN;
|
|
CREATE TABLE parent (i int, v int);
|
|
CREATE TABLE child_a(options text) INHERITS(parent);
|
|
SELECT create_immv('mv_ivm21', 'SELECT * FROM parent');
|
|
ERROR: inheritance parent is not supported on incrementally maintainable materialized view
|
|
ROLLBACK;
|
|
-- UNION statement is not supported
|
|
SELECT create_immv('mv_ivm22', 'SELECT i,j FROM mv_base_a UNION ALL SELECT i,k FROM mv_base_b');
|
|
ERROR: UNION/INTERSECT/EXCEPT statements are not supported on incrementally maintainable materialized view
|
|
-- empty target list is not allowed with IVM
|
|
SELECT create_immv('mv_ivm25', 'SELECT FROM mv_base_a');
|
|
ERROR: empty target list is not supported on incrementally maintainable materialized view
|
|
-- FOR UPDATE/SHARE is not supported
|
|
SELECT create_immv('mv_ivm26', 'SELECT i,j FROM mv_base_a FOR UPDATE');
|
|
ERROR: FOR UPDATE/SHARE clause is not supported on incrementally maintainable materialized view
|
|
-- tartget list cannot contain ivm column that start with '__ivm'
|
|
SELECT create_immv('mv_ivm28', 'SELECT i AS "__ivm_count__" FROM mv_base_a');
|
|
ERROR: column name __ivm_count__ is not supported on incrementally maintainable materialized view
|
|
-- VALUES is not supported
|
|
SELECT create_immv('mv_ivm_only_values1', 'values(1)');
|
|
ERROR: VALUES is not supported on incrementally maintainable materialized view
|
|
-- base table which has row level security
|
|
DROP USER IF EXISTS ivm_admin;
|
|
NOTICE: role "ivm_admin" does not exist, skipping
|
|
DROP USER IF EXISTS ivm_user;
|
|
NOTICE: role "ivm_user" does not exist, skipping
|
|
CREATE USER ivm_admin;
|
|
CREATE USER ivm_user;
|
|
SET SESSION AUTHORIZATION ivm_admin;
|
|
CREATE TABLE rls_tbl(id int, data text, owner name);
|
|
INSERT INTO rls_tbl VALUES
|
|
(1,'foo','ivm_user'),
|
|
(2,'bar','postgres');
|
|
CREATE TABLE num_tbl(id int, num text);
|
|
INSERT INTO num_tbl VALUES
|
|
(1,'one'),
|
|
(2,'two'),
|
|
(3,'three'),
|
|
(4,'four');
|
|
CREATE POLICY rls_tbl_policy ON rls_tbl FOR SELECT TO PUBLIC USING(owner = current_user);
|
|
CREATE POLICY rls_tbl_policy2 ON rls_tbl FOR INSERT TO PUBLIC WITH CHECK(current_user LIKE 'ivm_%');
|
|
ALTER TABLE rls_tbl ENABLE ROW LEVEL SECURITY;
|
|
GRANT ALL on rls_tbl TO PUBLIC;
|
|
GRANT ALL on num_tbl TO PUBLIC;
|
|
SET SESSION AUTHORIZATION ivm_user;
|
|
SELECT create_immv('ivm_rls', 'SELECT * FROM rls_tbl');
|
|
NOTICE: could not create an index on immv "ivm_rls" 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
|
|
-------------
|
|
1
|
|
(1 row)
|
|
|
|
SELECT id, data, owner FROM ivm_rls ORDER BY 1,2,3;
|
|
id | data | owner
|
|
----+------+----------
|
|
1 | foo | ivm_user
|
|
(1 row)
|
|
|
|
INSERT INTO rls_tbl VALUES
|
|
(3,'baz','ivm_user'),
|
|
(4,'qux','postgres');
|
|
SELECT id, data, owner FROM ivm_rls ORDER BY 1,2,3;
|
|
id | data | owner
|
|
----+------+----------
|
|
1 | foo | ivm_user
|
|
3 | baz | ivm_user
|
|
(2 rows)
|
|
|
|
SELECT create_immv('ivm_rls2', 'SELECT * FROM rls_tbl JOIN num_tbl USING(id)');
|
|
NOTICE: could not create an index on immv "ivm_rls2" 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
|
|
-------------
|
|
2
|
|
(1 row)
|
|
|
|
RESET SESSION AUTHORIZATION;
|
|
WITH
|
|
x AS (UPDATE rls_tbl SET data = data || '_2' where id in (3,4)),
|
|
y AS (UPDATE num_tbl SET num = num || '_2' where id in (3,4))
|
|
SELECT;
|
|
--
|
|
(1 row)
|
|
|
|
SELECT * FROM ivm_rls2 ORDER BY 1,2,3;
|
|
id | data | owner | num
|
|
----+-------+----------+---------
|
|
1 | foo | ivm_user | one
|
|
3 | baz_2 | ivm_user | three_2
|
|
(2 rows)
|
|
|
|
DROP TABLE rls_tbl CASCADE;
|
|
NOTICE: drop cascades to 2 other objects
|
|
DETAIL: drop cascades to table ivm_rls
|
|
drop cascades to table ivm_rls2
|
|
DROP TABLE num_tbl CASCADE;
|
|
DROP USER ivm_user;
|
|
DROP USER ivm_admin;
|
|
-- prevent IMMV chanages
|
|
INSERT INTO mv_ivm_1 VALUES(1,1,1);
|
|
ERROR: cannot change materialized view "mv_ivm_1"
|
|
UPDATE mv_ivm_1 SET k = 1 WHERE i = 1;
|
|
ERROR: cannot change materialized view "mv_ivm_1"
|
|
DELETE FROM mv_ivm_1;
|
|
ERROR: cannot change materialized view "mv_ivm_1"
|
|
TRUNCATE mv_ivm_1;
|
|
ERROR: cannot change materialized view "mv_ivm_1"
|
|
DROP TABLE mv_base_b CASCADE;
|
|
NOTICE: drop cascades to 3 other objects
|
|
DETAIL: drop cascades to table mv_ivm_1
|
|
drop cascades to view b_view
|
|
drop cascades to materialized view b_mview
|
|
DROP TABLE mv_base_a CASCADE;
|