Add regression tests for some cases
Per sub-queries support, a test for join with subquery is added. In passing, the order of tests are fixed with according to that in pgsql-ivm. Also, some other tests related to aggregates and sub-queries are added.
This commit is contained in:
parent
6faf0b3baa
commit
f1e36a9781
2 changed files with 128 additions and 67 deletions
|
|
@ -14,7 +14,6 @@ INSERT INTO mv_base_b VALUES
|
|||
(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.
|
||||
|
|
@ -474,59 +473,6 @@ SELECT * FROM mv_ivm_min_max;
|
|||
| | 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;
|
||||
|
|
@ -657,6 +603,68 @@ SELECT * FROM mv_ri ORDER BY i2;
|
|||
10 | 10
|
||||
(2 rows)
|
||||
|
||||
ROLLBACK;
|
||||
-- not support subquery for using EXISTS()
|
||||
SELECT create_immv('mv_ivm_exists_subquery', 'SELECT a.i, a.j FROM mv_base_a a WHERE EXISTS(SELECT 1 FROM mv_base_b b WHERE a.i = b.i)');
|
||||
ERROR: this query is not allowed on incrementally maintainable materialized view
|
||||
HINT: Only simple subquery is supported
|
||||
-- support simple subquery in FROM clause
|
||||
BEGIN;
|
||||
SELECT create_immv('mv_ivm_subquery', '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_subquery" 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)
|
||||
|
||||
INSERT INTO mv_base_a VALUES(2,20);
|
||||
INSERT INTO mv_base_b VALUES(3,300);
|
||||
SELECT * FROM mv_ivm_subquery ORDER BY i,j;
|
||||
i | j
|
||||
---+----
|
||||
1 | 10
|
||||
2 | 20
|
||||
2 | 20
|
||||
3 | 30
|
||||
3 | 30
|
||||
4 | 40
|
||||
(6 rows)
|
||||
|
||||
ROLLBACK;
|
||||
-- support join subquery in FROM clause
|
||||
BEGIN;
|
||||
SELECT create_immv('mv_ivm_join_subquery', 'SELECT i, j, k FROM ( SELECT i, a.j, b.k FROM mv_base_b b INNER JOIN mv_base_a a USING(i)) tmp');
|
||||
NOTICE: could not create an index on immv "mv_ivm_join_subquery" 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)
|
||||
|
||||
WITH
|
||||
ai AS (INSERT INTO mv_base_a VALUES (1,11),(2,22) RETURNING 0),
|
||||
bi AS (INSERT INTO mv_base_b VALUES (1,111),(3,133) RETURNING 0),
|
||||
bd AS (DELETE FROM mv_base_b WHERE i = 4 RETURNING 0)
|
||||
SELECT;
|
||||
--
|
||||
(1 row)
|
||||
|
||||
SELECT * FROM mv_ivm_join_subquery ORDER BY i,j,k;
|
||||
i | j | k
|
||||
---+----+-----
|
||||
1 | 10 | 101
|
||||
1 | 10 | 111
|
||||
1 | 11 | 101
|
||||
1 | 11 | 111
|
||||
2 | 20 | 102
|
||||
2 | 22 | 102
|
||||
3 | 30 | 103
|
||||
3 | 30 | 133
|
||||
(8 rows)
|
||||
|
||||
ROLLBACK;
|
||||
-- views including NULL
|
||||
BEGIN;
|
||||
|
|
@ -891,6 +899,15 @@ ERROR: TABLESAMPLE clause is not supported on incrementally maintainable materi
|
|||
-- 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
|
||||
-- aggregate function with some options is not supported
|
||||
SELECT create_immv('mv_ivm17', 'SELECT COUNT(*) FILTER(WHERE i < 3) FROM mv_base_a');
|
||||
ERROR: aggregate function with FILTER clause is not supported on incrementally maintainable materialized view
|
||||
SELECT create_immv('mv_ivm18', 'SELECT COUNT(DISTINCT i) FROM mv_base_a');
|
||||
ERROR: aggregate function with DISTINCT arguments is not supported on incrementally maintainable materialized view
|
||||
SELECT create_immv('mv_ivm19', 'SELECT array_agg(j ORDER BY i DESC) FROM mv_base_a');
|
||||
ERROR: aggregate function with ORDER clause is not supported on incrementally maintainable materialized view
|
||||
SELECT create_immv('mv_ivm20', 'SELECT i,SUM(j) FROM mv_base_a GROUP BY GROUPING SETS((i),())');
|
||||
ERROR: GROUPING SETS, ROLLUP, or CUBE clauses is not supported on incrementally maintainable materialized view
|
||||
-- inheritance parent is not supported
|
||||
BEGIN;
|
||||
CREATE TABLE parent (i int, v int);
|
||||
|
|
@ -901,18 +918,33 @@ 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
|
||||
-- DISTINCT clause in nested query are not supported
|
||||
SELECT create_immv('mv_ivm23', 'SELECT * FROM (SELECT DISTINCT i,j FROM mv_base_a) AS tmp');;
|
||||
ERROR: DISTINCT clause in nested query 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
|
||||
SELECT create_immv('mv_ivm27', 'SELECT * FROM (SELECT i,j FROM mv_base_a FOR UPDATE) AS tmp;');
|
||||
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
|
||||
-- expressions specified in GROUP BY must appear in the target list.
|
||||
SELECT create_immv('mv_ivm29', 'SELECT COUNT(i) FROM mv_base_a GROUP BY i;');
|
||||
ERROR: GROUP BY expression not appearing in select list is not supported on incrementally maintainable materialized view
|
||||
-- experssions containing an aggregate is not supported
|
||||
SELECT create_immv('mv_ivm30', 'SELECT sum(i)*0.5 FROM mv_base_a');
|
||||
ERROR: expression containing an aggregate in it is not supported on incrementally maintainable materialized view
|
||||
SELECT create_immv('mv_ivm31', 'SELECT sum(i)/sum(j) FROM mv_base_a');
|
||||
ERROR: expression containing an aggregate in it 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
|
||||
SELECT create_immv('mv_ivm_only_values2', 'SELECT * FROM (values(1)) AS tmp');
|
||||
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
|
||||
|
|
|
|||
|
|
@ -16,7 +16,6 @@ INSERT INTO mv_base_b VALUES
|
|||
(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)');
|
||||
SELECT * FROM mv_ivm_1 ORDER BY 1,2,3;
|
||||
|
||||
|
|
@ -151,18 +150,6 @@ DELETE FROM mv_base_a;
|
|||
SELECT * FROM mv_ivm_min_max;
|
||||
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');
|
||||
SELECT * FROM mv_ivm_subquery01 ORDER BY 1,2;
|
||||
INSERT INTO mv_base_b VALUES(5,105);
|
||||
SELECT * FROM mv_ivm_subquery01 ORDER BY 1,2;
|
||||
UPDATE mv_base_a SET j = 0 WHERE i = 1;
|
||||
SELECT * FROM mv_ivm_subquery01 ORDER BY 1,2;
|
||||
DELETE FROM mv_base_b WHERE (i,k) = (5,105);
|
||||
SELECT * FROM mv_ivm_subquery01 ORDER BY 1,2;
|
||||
ROLLBACK;
|
||||
|
||||
-- support self join view and multiple change on the same table
|
||||
BEGIN;
|
||||
CREATE TABLE base_t (i int, v int);
|
||||
|
|
@ -213,6 +200,30 @@ DELETE FROM ri1 WHERE i=2;
|
|||
SELECT * FROM mv_ri ORDER BY i2;
|
||||
ROLLBACK;
|
||||
|
||||
-- not support subquery for using EXISTS()
|
||||
SELECT create_immv('mv_ivm_exists_subquery', 'SELECT a.i, a.j FROM mv_base_a a WHERE EXISTS(SELECT 1 FROM mv_base_b b WHERE a.i = b.i)');
|
||||
|
||||
-- support simple subquery in FROM clause
|
||||
BEGIN;
|
||||
SELECT create_immv('mv_ivm_subquery', 'SELECT a.i,a.j FROM mv_base_a a,( SELECT * FROM mv_base_b) b WHERE a.i = b.i');
|
||||
INSERT INTO mv_base_a VALUES(2,20);
|
||||
INSERT INTO mv_base_b VALUES(3,300);
|
||||
SELECT * FROM mv_ivm_subquery ORDER BY i,j;
|
||||
|
||||
ROLLBACK;
|
||||
|
||||
-- support join subquery in FROM clause
|
||||
BEGIN;
|
||||
SELECT create_immv('mv_ivm_join_subquery', 'SELECT i, j, k FROM ( SELECT i, a.j, b.k FROM mv_base_b b INNER JOIN mv_base_a a USING(i)) tmp');
|
||||
WITH
|
||||
ai AS (INSERT INTO mv_base_a VALUES (1,11),(2,22) RETURNING 0),
|
||||
bi AS (INSERT INTO mv_base_b VALUES (1,111),(3,133) RETURNING 0),
|
||||
bd AS (DELETE FROM mv_base_b WHERE i = 4 RETURNING 0)
|
||||
SELECT;
|
||||
SELECT * FROM mv_ivm_join_subquery ORDER BY i,j,k;
|
||||
|
||||
ROLLBACK;
|
||||
|
||||
-- views including NULL
|
||||
BEGIN;
|
||||
CREATE TABLE base_t (i int, v int);
|
||||
|
|
@ -347,6 +358,12 @@ SELECT create_immv('mv_ivm15', 'SELECT i, j FROM mv_base_a TABLESAMPLE SYSTEM(50
|
|||
-- window functions are not supported
|
||||
SELECT create_immv('mv_ivm16', 'SELECT *, cume_dist() OVER (ORDER BY i) AS rank FROM mv_base_a');
|
||||
|
||||
-- aggregate function with some options is not supported
|
||||
SELECT create_immv('mv_ivm17', 'SELECT COUNT(*) FILTER(WHERE i < 3) FROM mv_base_a');
|
||||
SELECT create_immv('mv_ivm18', 'SELECT COUNT(DISTINCT i) FROM mv_base_a');
|
||||
SELECT create_immv('mv_ivm19', 'SELECT array_agg(j ORDER BY i DESC) FROM mv_base_a');
|
||||
SELECT create_immv('mv_ivm20', 'SELECT i,SUM(j) FROM mv_base_a GROUP BY GROUPING SETS((i),())');
|
||||
|
||||
-- inheritance parent is not supported
|
||||
BEGIN;
|
||||
CREATE TABLE parent (i int, v int);
|
||||
|
|
@ -357,17 +374,29 @@ 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');
|
||||
|
||||
-- DISTINCT clause in nested query are not supported
|
||||
SELECT create_immv('mv_ivm23', 'SELECT * FROM (SELECT DISTINCT i,j FROM mv_base_a) AS tmp');;
|
||||
|
||||
-- empty target list is not allowed with IVM
|
||||
SELECT create_immv('mv_ivm25', 'SELECT FROM mv_base_a');
|
||||
|
||||
-- FOR UPDATE/SHARE is not supported
|
||||
SELECT create_immv('mv_ivm26', 'SELECT i,j FROM mv_base_a FOR UPDATE');
|
||||
SELECT create_immv('mv_ivm27', 'SELECT * FROM (SELECT i,j FROM mv_base_a FOR UPDATE) AS tmp;');
|
||||
|
||||
-- tartget list cannot contain ivm column that start with '__ivm'
|
||||
SELECT create_immv('mv_ivm28', 'SELECT i AS "__ivm_count__" FROM mv_base_a');
|
||||
|
||||
-- expressions specified in GROUP BY must appear in the target list.
|
||||
SELECT create_immv('mv_ivm29', 'SELECT COUNT(i) FROM mv_base_a GROUP BY i;');
|
||||
|
||||
-- experssions containing an aggregate is not supported
|
||||
SELECT create_immv('mv_ivm30', 'SELECT sum(i)*0.5 FROM mv_base_a');
|
||||
SELECT create_immv('mv_ivm31', 'SELECT sum(i)/sum(j) FROM mv_base_a');
|
||||
|
||||
-- VALUES is not supported
|
||||
SELECT create_immv('mv_ivm_only_values1', 'values(1)');
|
||||
SELECT create_immv('mv_ivm_only_values2', 'SELECT * FROM (values(1)) AS tmp');
|
||||
|
||||
|
||||
-- base table which has row level security
|
||||
|
|
|
|||
Loading…
Reference in a new issue