Allow "COPY table TO" command to copy rows from materialized views.
authorFujii Masao <[email protected]>
Fri, 4 Apr 2025 10:32:00 +0000 (19:32 +0900)
committerFujii Masao <[email protected]>
Fri, 4 Apr 2025 10:32:00 +0000 (19:32 +0900)
Previously, "COPY table TO" command worked only with plain tables and
did not support materialized views, even when they were populated and
had physical storage. To copy rows from materialized views,
"COPY (query) TO" command had to be used, instead.

This commit extends "COPY table TO" to support populated materialized
views directly, improving usability and performance, as "COPY table TO"
is generally faster than "COPY (query) TO". Note that copying from
unpopulated materialized views will still result in an error.

Author: jian he <[email protected]>
Reviewed-by: Kirill Reshke <[email protected]>
Reviewed-by: David G. Johnston <[email protected]>
Reviewed-by: Vignesh C <[email protected]>
Reviewed-by: Fujii Masao <[email protected]>
Discussion: https://postgr.es/m/CACJufxHVxnyRYy67hiPePNCPwVBMzhTQ6FaL9_Te5On9udG=yg@mail.gmail.com

doc/src/sgml/ref/copy.sgml
src/backend/commands/copyto.c
src/test/regress/expected/copy.out
src/test/regress/sql/copy.sql

index df093da97c5ed31a9605024fb2fe33e81fd0d3da..d6859276bed424546fac87e5ea1e0ff53ee3d6b2 100644 (file)
@@ -520,16 +520,16 @@ COPY <replaceable class="parameter">count</replaceable>
   <title>Notes</title>
 
    <para>
-    <command>COPY TO</command> can be used only with plain
-    tables, not views, and does not copy rows from child tables
-    or child partitions.  For example, <literal>COPY <replaceable
-    class="parameter">table</replaceable> TO</literal> copies
-    the same rows as <literal>SELECT * FROM ONLY <replaceable
-    class="parameter">table</replaceable></literal>.
-    The syntax <literal>COPY (SELECT * FROM <replaceable
-    class="parameter">table</replaceable>) TO ...</literal> can be used to
-    dump all of the rows in an inheritance hierarchy, partitioned table,
-    or view.
+    <command>COPY TO</command> can be used with plain
+    tables and populated materialized views.
+    For example,
+    <literal>COPY <replaceable class="parameter">table</replaceable>
+    TO</literal> copies the same rows as
+    <literal>SELECT * FROM ONLY <replaceable class="parameter">table</replaceable></literal>.
+    However it doesn't directly support other relation types,
+    such as partitioned tables, inheritance child tables, or views.
+    To copy all rows from such relations, use <literal>COPY (SELECT * FROM
+    <replaceable class="parameter">table</replaceable>) TO</literal>.
    </para>
 
    <para>
index 84a3f3879a87015ecaa9418d69a083d3ca3b9bb6..f87e405351d110d3656bc06a1cfa475094bb30da 100644 (file)
@@ -653,11 +653,14 @@ BeginCopyTo(ParseState *pstate,
                            RelationGetRelationName(rel)),
                     errhint("Try the COPY (SELECT ...) TO variant.")));
        else if (rel->rd_rel->relkind == RELKIND_MATVIEW)
-           ereport(ERROR,
-                   (errcode(ERRCODE_WRONG_OBJECT_TYPE),
-                    errmsg("cannot copy from materialized view \"%s\"",
-                           RelationGetRelationName(rel)),
-                    errhint("Try the COPY (SELECT ...) TO variant.")));
+       {
+           if (!RelationIsPopulated(rel))
+               ereport(ERROR,
+                       errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+                       errmsg("cannot copy from unpopulated materialized view \"%s\"",
+                              RelationGetRelationName(rel)),
+                       errhint("Use the REFRESH MATERIALIZED VIEW command."));
+       }
        else if (rel->rd_rel->relkind == RELKIND_FOREIGN_TABLE)
            ereport(ERROR,
                    (errcode(ERRCODE_WRONG_OBJECT_TYPE),
index 06bae8c61aebe1bde0b32bb31cc90f123493b739..8d5a06563c44a677dbcd1b5ef62ae654a7e0019a 100644 (file)
@@ -338,3 +338,15 @@ create foreign table copytest_foreign_table (a int) server copytest_server;
 copy copytest_foreign_table from stdin (freeze);
 ERROR:  cannot perform COPY FREEZE on a foreign table
 rollback;
+-- Tests for COPY TO with materialized views.
+-- COPY TO should fail for an unpopulated materialized view
+-- but succeed for a populated one.
+CREATE MATERIALIZED VIEW copytest_mv AS SELECT 1 AS id WITH NO DATA;
+COPY copytest_mv(id) TO stdout WITH (header);
+ERROR:  cannot copy from unpopulated materialized view "copytest_mv"
+HINT:  Use the REFRESH MATERIALIZED VIEW command.
+REFRESH MATERIALIZED VIEW copytest_mv;
+COPY copytest_mv(id) TO stdout WITH (header);
+id
+1
+DROP MATERIALIZED VIEW copytest_mv;
index 3009bdfdf898bf8488af7179564090c8445f99fe..f0b88a23db853bbd04318976f7563c76070dc663 100644 (file)
@@ -366,3 +366,12 @@ copy copytest_foreign_table from stdin (freeze);
 1
 \.
 rollback;
+
+-- Tests for COPY TO with materialized views.
+-- COPY TO should fail for an unpopulated materialized view
+-- but succeed for a populated one.
+CREATE MATERIALIZED VIEW copytest_mv AS SELECT 1 AS id WITH NO DATA;
+COPY copytest_mv(id) TO stdout WITH (header);
+REFRESH MATERIALIZED VIEW copytest_mv;
+COPY copytest_mv(id) TO stdout WITH (header);
+DROP MATERIALIZED VIEW copytest_mv;