Per report from Fujii Masao, with regression test using his example.
*
* Don't even think about it unless we have a shot at releasing a goodly
* number of pages. Otherwise, the time taken isn't worth it.
+ *
+ * Leave a populated materialized view with at least one page.
*/
+ if (onerel->rd_rel->relkind == RELKIND_MATVIEW &&
+ vacrelstats->nonempty_pages == 0)
+ vacrelstats->nonempty_pages = 1;
+
possibly_freeable = vacrelstats->rel_pages - vacrelstats->nonempty_pages;
if (possibly_freeable > 0 &&
(possibly_freeable >= REL_TRUNCATE_MINIMUM ||
DETAIL: drop cascades to view v_test2
drop cascades to materialized view mv_test2
drop cascades to materialized view mv_test3
+-- test that vacuum does not make empty matview look unpopulated
+CREATE TABLE hoge (i int);
+INSERT INTO hoge VALUES (generate_series(1,100000));
+CREATE MATERIALIZED VIEW hogeview AS SELECT * FROM hoge WHERE i % 2 = 0;
+CREATE INDEX hogeviewidx ON hogeview (i);
+DELETE FROM hoge;
+REFRESH MATERIALIZED VIEW hogeview;
+SELECT * FROM hogeview WHERE i < 10;
+ i
+---
+(0 rows)
+
+VACUUM ANALYZE;
+SELECT * FROM hogeview WHERE i < 10;
+ i
+---
+(0 rows)
+
+DROP TABLE hoge CASCADE;
+NOTICE: drop cascades to materialized view hogeview
SELECT pg_relation_is_scannable('mv_test3'::regclass);
DROP VIEW v_test1 CASCADE;
+
+-- test that vacuum does not make empty matview look unpopulated
+CREATE TABLE hoge (i int);
+INSERT INTO hoge VALUES (generate_series(1,100000));
+CREATE MATERIALIZED VIEW hogeview AS SELECT * FROM hoge WHERE i % 2 = 0;
+CREATE INDEX hogeviewidx ON hogeview (i);
+DELETE FROM hoge;
+REFRESH MATERIALIZED VIEW hogeview;
+SELECT * FROM hogeview WHERE i < 10;
+VACUUM ANALYZE;
+SELECT * FROM hogeview WHERE i < 10;
+DROP TABLE hoge CASCADE;