Allow TRUNCATE on base tables (#144)
When a base table is truncated, the view content will be empty if the view definition query does not contain an aggregate without a GROUP clause. Therefore, such views can be truncated. Aggregate views without a GROUP clause always have one row. Therefore, if a base table is truncated, the view will not be empty and will contain a row with NULL value (or 0 for count()). So, in this case, we refresh the view instead of truncating it.
This commit is contained in:
parent
57c8bac1a0
commit
d99aeb848e
4 changed files with 161 additions and 3 deletions
|
|
@ -509,9 +509,11 @@ CreateIvmTriggersOnBaseTablesRecurse(Query *qry, Node *node, Oid matviewOid,
|
|||
CreateIvmTrigger(rte->relid, matviewOid, TRIGGER_TYPE_INSERT, TRIGGER_TYPE_BEFORE, ex_lock);
|
||||
CreateIvmTrigger(rte->relid, matviewOid, TRIGGER_TYPE_DELETE, TRIGGER_TYPE_BEFORE, ex_lock);
|
||||
CreateIvmTrigger(rte->relid, matviewOid, TRIGGER_TYPE_UPDATE, TRIGGER_TYPE_BEFORE, ex_lock);
|
||||
CreateIvmTrigger(rte->relid, matviewOid, TRIGGER_TYPE_TRUNCATE, TRIGGER_TYPE_BEFORE, true);
|
||||
CreateIvmTrigger(rte->relid, matviewOid, TRIGGER_TYPE_INSERT, TRIGGER_TYPE_AFTER, ex_lock);
|
||||
CreateIvmTrigger(rte->relid, matviewOid, TRIGGER_TYPE_DELETE, TRIGGER_TYPE_AFTER, ex_lock);
|
||||
CreateIvmTrigger(rte->relid, matviewOid, TRIGGER_TYPE_UPDATE, TRIGGER_TYPE_AFTER, ex_lock);
|
||||
CreateIvmTrigger(rte->relid, matviewOid, TRIGGER_TYPE_TRUNCATE, TRIGGER_TYPE_AFTER, true);
|
||||
|
||||
*relids = bms_add_member(*relids, rte->relid);
|
||||
}
|
||||
|
|
@ -577,6 +579,9 @@ CreateIvmTrigger(Oid relOid, Oid viewOid, int16 type, int16 timing, bool ex_lock
|
|||
case TRIGGER_TYPE_UPDATE:
|
||||
ivm_trigger->trigname = (timing == TRIGGER_TYPE_BEFORE ? "IVM_trigger_upd_before" : "IVM_trigger_upd_after");
|
||||
break;
|
||||
case TRIGGER_TYPE_TRUNCATE:
|
||||
ivm_trigger->trigname = (timing == TRIGGER_TYPE_BEFORE ? "IVM_trigger_truncate_before" : "IVM_trigger_truncate_after");
|
||||
break;
|
||||
default:
|
||||
elog(ERROR, "unsupported trigger type");
|
||||
}
|
||||
|
|
|
|||
|
|
@ -77,6 +77,23 @@ SELECT * FROM mv_ivm_1 ORDER BY 1,2,3;
|
|||
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'
|
||||
|
|
@ -245,6 +262,27 @@ SELECT * FROM mv_ivm_agg ORDER BY 1,2,3;
|
|||
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;
|
||||
|
|
@ -277,6 +315,31 @@ SELECT * FROM mv_ivm_group ORDER BY 1;
|
|||
| 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;
|
||||
|
|
|
|||
69
matview.c
69
matview.c
|
|
@ -816,9 +816,6 @@ IVM_immediate_maintenance(PG_FUNCTION_ARGS)
|
|||
|
||||
matviewRel = table_open(matviewOid, NoLock);
|
||||
|
||||
/* get view query*/
|
||||
query = get_immv_query(matviewRel);
|
||||
|
||||
/* Make sure IMMV is a table. */
|
||||
Assert(matviewRel->rd_rel->relkind == RELKIND_RELATION);
|
||||
|
||||
|
|
@ -848,6 +845,72 @@ IVM_immediate_maintenance(PG_FUNCTION_ARGS)
|
|||
save_sec_context | SECURITY_RESTRICTED_OPERATION);
|
||||
save_nestlevel = NewGUCNestLevel();
|
||||
|
||||
/* get view query*/
|
||||
query = get_immv_query(matviewRel);
|
||||
|
||||
/*
|
||||
* When a base table is truncated, the view content will be empty if the
|
||||
* view definition query does not contain an aggregate without a GROUP clause.
|
||||
* Therefore, such views can be truncated.
|
||||
*
|
||||
* Aggregate views without a GROUP clause always have one row. Therefore,
|
||||
* if a base table is truncated, the view will not be empty and will contain
|
||||
* a row with NULL value (or 0 for count()). So, in this case, we refresh the
|
||||
* view instead of truncating it.
|
||||
*/
|
||||
if (TRIGGER_FIRED_BY_TRUNCATE(trigdata->tg_event))
|
||||
{
|
||||
if (!(query->hasAggs && query->groupClause == NIL))
|
||||
{
|
||||
OpenImmvIncrementalMaintenance();
|
||||
ExecuteTruncateGuts(list_make1(matviewRel), list_make1_oid(matviewOid),
|
||||
NIL, DROP_RESTRICT, false);
|
||||
CloseImmvIncrementalMaintenance();
|
||||
}
|
||||
else
|
||||
{
|
||||
Oid OIDNewHeap;
|
||||
DestReceiver *dest;
|
||||
uint64 processed = 0;
|
||||
Query *dataQuery = rewriteQueryForIMMV(query, NIL);
|
||||
char relpersistence = matviewRel->rd_rel->relpersistence;
|
||||
|
||||
/*
|
||||
* Create the transient table that will receive the regenerated data. Lock
|
||||
* it against access by any other process until commit (by which time it
|
||||
* will be gone).
|
||||
*/
|
||||
OIDNewHeap = make_new_heap(matviewOid, matviewRel->rd_rel->reltablespace,
|
||||
relpersistence, ExclusiveLock);
|
||||
LockRelationOid(OIDNewHeap, AccessExclusiveLock);
|
||||
dest = CreateTransientRelDestReceiver(OIDNewHeap);
|
||||
|
||||
/* Generate the data */
|
||||
processed = refresh_immv_datafill(dest, dataQuery, NULL, NULL, "");
|
||||
refresh_by_heap_swap(matviewOid, OIDNewHeap, relpersistence);
|
||||
|
||||
/* Inform cumulative stats system about our activity */
|
||||
pgstat_count_truncate(matviewRel);
|
||||
pgstat_count_heap_insert(matviewRel, processed);
|
||||
}
|
||||
|
||||
/* Clean up hash entry and delete tuplestores */
|
||||
clean_up_IVM_hash_entry(entry);
|
||||
|
||||
/* Pop the original snapshot. */
|
||||
PopActiveSnapshot();
|
||||
|
||||
table_close(matviewRel, NoLock);
|
||||
|
||||
/* Roll back any GUC changes */
|
||||
AtEOXact_GUC(false, save_nestlevel);
|
||||
|
||||
/* Restore userid and security context */
|
||||
SetUserIdAndSecContext(save_userid, save_sec_context);
|
||||
|
||||
return PointerGetDatum(NULL);
|
||||
}
|
||||
|
||||
/*
|
||||
* rewrite query for calculating deltas
|
||||
*/
|
||||
|
|
|
|||
|
|
@ -31,6 +31,17 @@ SELECT * FROM mv_ivm_1 ORDER BY 1,2,3;
|
|||
ROLLBACK;
|
||||
SELECT * FROM mv_ivm_1 ORDER BY 1,2,3;
|
||||
|
||||
-- TRUNCATE a base table in join views
|
||||
BEGIN;
|
||||
TRUNCATE mv_base_a;
|
||||
SELECT * FROM mv_ivm_1;
|
||||
ROLLBACK;
|
||||
|
||||
BEGIN;
|
||||
TRUNCATE mv_base_b;
|
||||
SELECT * FROM mv_ivm_1;
|
||||
ROLLBACK;
|
||||
|
||||
-- some query syntax
|
||||
BEGIN;
|
||||
CREATE FUNCTION ivm_func() RETURNS int LANGUAGE 'sql'
|
||||
|
|
@ -71,6 +82,14 @@ INSERT INTO mv_base_a VALUES(2,100);
|
|||
SELECT * FROM mv_ivm_agg ORDER BY 1,2,3;
|
||||
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');
|
||||
TRUNCATE mv_base_a;
|
||||
SELECT sum, count FROM mv_ivm_agg;
|
||||
SELECT i, SUM(j), COUNT(*) FROM mv_base_a GROUP BY i;
|
||||
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');
|
||||
|
|
@ -81,6 +100,14 @@ DELETE FROM mv_base_a;
|
|||
SELECT * FROM mv_ivm_group ORDER BY 1;
|
||||
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');
|
||||
TRUNCATE mv_base_a;
|
||||
SELECT sum, count, avg FROM mv_ivm_group;
|
||||
SELECT SUM(j), COUNT(j), AVG(j) FROM mv_base_a;
|
||||
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');
|
||||
|
|
|
|||
Loading…
Reference in a new issue