Skip to content

HTTPS clone URL

Subversion checkout URL

You can clone with HTTPS or Subversion.

Download ZIP
Browse files

Add a materialized view relations.

A materialized view has a rule just like a view and a heap and
other physical properties like a table.  The rule is only used to
populate the table, references in queries refer to the
materialized data.

This is a minimal implementation, but should still be useful in
many cases.  Currently data is only populated "on demand" by the
CREATE MATERIALIZED VIEW and REFRESH MATERIALIZED VIEW statements.
It is expected that future releases will add incremental updates
with various timings, and that a more refined concept of defining
what is "fresh" data will be developed.  At some point it may even
be possible to have queries use a materialized in place of
references to underlying tables, but that requires the other
above-mentioned features to be working first.

Much of the documentation work by Robert Haas.
Review by Noah Misch, Thom Brown, Robert Haas, Marko Tiikkaja
Security review by KaiGai Kohei, with a decision on how best to
implement sepgsql still pending.
  • Loading branch information...
commit 3bf3ab8c563699138be02f9dc305b7b77a724307 1 parent b15a6da
@kgrittn kgrittn authored
Showing with 4,240 additions and 438 deletions.
  1. +2 −2 contrib/oid2name/oid2name.c
  2. +1 −1  contrib/pg_upgrade/info.c
  3. +2 −2 contrib/pg_upgrade/pg_upgrade.c
  4. +3 −0  contrib/pg_upgrade/version_old_8_3.c
  5. +1 −0  contrib/pgstattuple/pgstattuple.c
  6. +1 −1  contrib/vacuumlo/vacuumlo.c
  7. +5 −4 doc/src/sgml/catalogs.sgml
  8. +16 −7 doc/src/sgml/func.sgml
  9. +4 −0 doc/src/sgml/ref/allfiles.sgml
  10. +1 −0  doc/src/sgml/ref/alter_extension.sgml
  11. +167 −0 doc/src/sgml/ref/alter_materialized_view.sgml
  12. +2 −0  doc/src/sgml/ref/comment.sgml
  13. +2 −2 doc/src/sgml/ref/create_index.sgml
  14. +154 −0 doc/src/sgml/ref/create_materialized_view.sgml
  15. +1 −0  doc/src/sgml/ref/create_table_as.sgml
  16. +1 −0  doc/src/sgml/ref/create_view.sgml
  17. +114 −0 doc/src/sgml/ref/drop_materialized_view.sgml
  18. +113 −0 doc/src/sgml/ref/refresh_materialized_view.sgml
  19. +1 −0  doc/src/sgml/ref/security_label.sgml
  20. +4 −0 doc/src/sgml/reference.sgml
  21. +200 −0 doc/src/sgml/rules.sgml
  22. +2 −0  src/backend/access/common/reloptions.c
  23. +6 −3 src/backend/access/heap/heapam.c
  24. +6 −4 src/backend/access/heap/tuptoaster.c
  25. +2 −0  src/backend/catalog/aclchk.c
  26. +4 −0 src/backend/catalog/dependency.c
  27. +28 −3 src/backend/catalog/heap.c
  28. +9 −0 src/backend/catalog/objectaddress.c
  29. +20 −6 src/backend/catalog/system_views.sql
  30. +3 −2 src/backend/catalog/toasting.c
  31. +1 −1  src/backend/commands/Makefile
  32. +2 −0  src/backend/commands/alter.c
  33. +5 −4 src/backend/commands/analyze.c
  34. +18 −0 src/backend/commands/cluster.c
  35. +8 −6 src/backend/commands/comment.c
  36. +11 −0 src/backend/commands/copy.c
  37. +112 −25 src/backend/commands/createas.c
  38. +2 −0  src/backend/commands/event_trigger.c
  39. +15 −20 src/backend/commands/explain.c
  40. +4 −2 src/backend/commands/indexcmds.c
  41. +374 −0 src/backend/commands/matview.c
  42. +1 −1  src/backend/commands/prepare.c
  43. +3 −2 src/backend/commands/seclabel.c
  44. +124 −34 src/backend/commands/tablecmds.c
  45. +2 −1  src/backend/commands/typecmds.c
  46. +13 −8 src/backend/commands/vacuum.c
  47. +13 −55 src/backend/commands/view.c
  48. +80 −0 src/backend/executor/execMain.c
  49. +7 −0 src/backend/executor/spi.c
  50. +17 −0 src/backend/nodes/copyfuncs.c
  51. +15 −0 src/backend/nodes/equalfuncs.c
  52. +2 −0  src/backend/nodes/outfuncs.c
  53. +2 −0  src/backend/nodes/readfuncs.c
  54. +1 −1  src/backend/optimizer/plan/planner.c
  55. +1 −0  src/backend/optimizer/util/plancat.c
  56. +26 −1 src/backend/parser/analyze.c
  57. +175 −6 src/backend/parser/gram.y
  58. +6 −0 src/backend/parser/parse_utilcmd.c
  59. +11 −11 src/backend/postmaster/autovacuum.c
  60. +1 −0  src/backend/postmaster/pgstat.c
  61. +5 −2 src/backend/rewrite/rewriteDefine.c
  62. +945 −0 src/backend/rewrite/rewriteDefine.c.orig
  63. +19 −1 src/backend/rewrite/rewriteHandler.c
  64. +3 −2 src/backend/storage/lmgr/predicate.c
  65. +7 −0 src/backend/tcop/dest.c
  66. +43 −7 src/backend/tcop/utility.c
  67. +24 −0 src/backend/utils/adt/dbsize.c
  68. +2 −2 src/backend/utils/adt/xml.c
  69. +26 −0 src/backend/utils/cache/relcache.c
  70. +1 −1  src/bin/initdb/initdb.c
  71. +4 −2 src/bin/pg_dump/common.c
  72. +3 −1 src/bin/pg_dump/pg_backup_archiver.c
  73. +318 −101 src/bin/pg_dump/pg_dump.c
  74. +3 −1 src/bin/pg_dump/pg_dump.h
  75. +12 −5 src/bin/pg_dump/pg_dump_sort.c
  76. +2 −1  src/bin/psql/command.c
  77. +93 −54 src/bin/psql/describe.c
  78. +1 −0  src/bin/psql/help.c
  79. +149 −27 src/bin/psql/tab-complete.c
  80. +1 −0  src/include/catalog/heap.h
  81. +1 −0  src/include/catalog/pg_class.h
  82. +2 −0  src/include/catalog/pg_proc.h
  83. +4 −0 src/include/commands/createas.h
  84. +2 −2 src/include/commands/explain.h
  85. +28 −0 src/include/commands/matview.h
  86. +2 −0  src/include/commands/tablecmds.h
  87. +2 −0  src/include/commands/view.h
  88. +1 −0  src/include/executor/executor.h
  89. +1 −0  src/include/nodes/nodes.h
  90. +17 −1 src/include/nodes/parsenodes.h
  91. +3 −1 src/include/nodes/primnodes.h
  92. +2 −0  src/include/parser/kwlist.h
  93. +2 −1  src/include/tcop/dest.h
  94. +1 −0  src/include/utils/builtins.h
  95. +1 −0  src/include/utils/rel.h
  96. +8 −2 src/pl/plpgsql/src/pl_comp.c
  97. +1 −0  src/pl/tcl/pltcl.c
  98. +406 −0 src/test/regress/expected/matview.out
  99. +27 −7 src/test/regress/expected/rules.out
  100. +11 −1 src/test/regress/output/misc.source
  101. +1 −1  src/test/regress/parallel_schedule
  102. +1 −0  src/test/regress/serial_schedule
  103. +128 −0 src/test/regress/sql/matview.sql
View
4 contrib/oid2name/oid2name.c
@@ -444,7 +444,7 @@ sql_exec_dumpalltables(PGconn *conn, struct options * opts)
" LEFT JOIN pg_catalog.pg_namespace n ON n.oid = c.relnamespace "
" LEFT JOIN pg_catalog.pg_database d ON d.datname = pg_catalog.current_database(),"
" pg_catalog.pg_tablespace t "
- "WHERE relkind IN ('r'%s%s) AND "
+ "WHERE relkind IN ('r', 'm'%s%s) AND "
" %s"
" t.oid = CASE"
" WHEN reltablespace <> 0 THEN reltablespace"
@@ -515,7 +515,7 @@ sql_exec_searchtables(PGconn *conn, struct options * opts)
" LEFT JOIN pg_catalog.pg_namespace n ON n.oid = c.relnamespace \n"
" LEFT JOIN pg_catalog.pg_database d ON d.datname = pg_catalog.current_database(),\n"
" pg_catalog.pg_tablespace t \n"
- "WHERE relkind IN ('r', 'i', 'S', 't') AND \n"
+ "WHERE relkind IN ('r', 'm', 'i', 'S', 't') AND \n"
" t.oid = CASE\n"
" WHEN reltablespace <> 0 THEN reltablespace\n"
" ELSE dattablespace\n"
View
2  contrib/pg_upgrade/info.c
@@ -282,7 +282,7 @@ get_rel_infos(ClusterInfo *cluster, DbInfo *dbinfo)
"CREATE TEMPORARY TABLE info_rels (reloid) AS SELECT c.oid "
"FROM pg_catalog.pg_class c JOIN pg_catalog.pg_namespace n "
" ON c.relnamespace = n.oid "
- "WHERE relkind IN ('r', 'i'%s) AND "
+ "WHERE relkind IN ('r', 'm', 'i'%s) AND "
/* exclude possible orphaned temp tables */
" ((n.nspname !~ '^pg_temp_' AND "
" n.nspname !~ '^pg_toast_temp_' AND "
View
4 contrib/pg_upgrade/pg_upgrade.c
@@ -525,8 +525,8 @@ set_frozenxids(void)
PQclear(executeQueryOrDie(conn,
"UPDATE pg_catalog.pg_class "
"SET relfrozenxid = '%u' "
- /* only heap and TOAST are vacuumed */
- "WHERE relkind IN ('r', 't')",
+ /* only heap, materialized view, and TOAST are vacuumed */
+ "WHERE relkind IN ('r', 'm', 't')",
old_cluster.controldata.chkpnt_nxtxid));
PQfinish(conn);
View
3  contrib/pg_upgrade/version_old_8_3.c
@@ -145,6 +145,7 @@ old_8_3_check_for_tsquery_usage(ClusterInfo *cluster)
"FROM pg_catalog.pg_class c, "
" pg_catalog.pg_namespace n, "
" pg_catalog.pg_attribute a "
+ /* materialized views didn't exist in 8.3, so no need to check 'm' */
"WHERE c.relkind = 'r' AND "
" c.oid = a.attrelid AND "
" NOT a.attisdropped AND "
@@ -323,6 +324,7 @@ old_8_3_rebuild_tsvector_tables(ClusterInfo *cluster, bool check_mode)
"FROM pg_catalog.pg_class c, "
" pg_catalog.pg_namespace n, "
" pg_catalog.pg_attribute a "
+ /* materialized views didn't exist in 8.3, so no need to check 'm' */
"WHERE c.relkind = 'r' AND "
" c.oid = a.attrelid AND "
" NOT a.attisdropped AND "
@@ -343,6 +345,7 @@ old_8_3_rebuild_tsvector_tables(ClusterInfo *cluster, bool check_mode)
"FROM pg_catalog.pg_class c, " \
" pg_catalog.pg_namespace n, " \
" pg_catalog.pg_attribute a " \
+ /* materialized views didn't exist in 8.3, so no need to check 'm' */ \
"WHERE c.relkind = 'r' AND " \
" c.oid = a.attrelid AND " \
" NOT a.attisdropped AND " \
View
1  contrib/pgstattuple/pgstattuple.c
@@ -216,6 +216,7 @@ pgstat_relation(Relation rel, FunctionCallInfo fcinfo)
switch (rel->rd_rel->relkind)
{
case RELKIND_RELATION:
+ case RELKIND_MATVIEW:
case RELKIND_TOASTVALUE:
case RELKIND_SEQUENCE:
return pgstat_heap(rel, fcinfo);
View
2  contrib/vacuumlo/vacuumlo.c
@@ -209,7 +209,7 @@ vacuumlo(const char *database, const struct _param * param)
strcat(buf, " AND a.atttypid = t.oid ");
strcat(buf, " AND c.relnamespace = s.oid ");
strcat(buf, " AND t.typname in ('oid', 'lo') ");
- strcat(buf, " AND c.relkind = 'r'");
+ strcat(buf, " AND c.relkind in ('r', 'm')");
strcat(buf, " AND s.nspname !~ '^pg_'");
res = PQexec(conn, buf);
if (PQresultStatus(res) != PGRES_TUPLES_OK)
View
9 doc/src/sgml/catalogs.sgml
@@ -1597,8 +1597,8 @@
The catalog <structname>pg_class</structname> catalogs tables and most
everything else that has columns or is otherwise similar to a
table. This includes indexes (but see also
- <structname>pg_index</structname>), sequences, views, composite types,
- and TOAST tables; see <structfield>relkind</>.
+ <structname>pg_index</structname>), sequences, views, materialized
+ views, composite types, and TOAST tables; see <structfield>relkind</>.
Below, when we mean all of these
kinds of objects we speak of <quote>relations</quote>. Not all
columns are meaningful for all relation types.
@@ -1789,8 +1789,9 @@
<entry></entry>
<entry>
<literal>r</> = ordinary table, <literal>i</> = index,
- <literal>S</> = sequence, <literal>v</> = view, <literal>c</> =
- composite type, <literal>t</> = TOAST table,
+ <literal>S</> = sequence, <literal>v</> = view,
+ <literal>m</> = materialized view,
+ <literal>c</> = composite type, <literal>t</> = TOAST table,
<literal>f</> = foreign table
</entry>
</row>
View
23 doc/src/sgml/func.sgml
@@ -13744,6 +13744,10 @@ SELECT pg_type_is_visible('myschema.widget'::regtype);
</indexterm>
<indexterm>
+ <primary>pg_relation_is_scannable</primary>
+ </indexterm>
+
+ <indexterm>
<primary>pg_typeof</primary>
</indexterm>
@@ -13867,29 +13871,29 @@ SELECT pg_type_is_visible('myschema.widget'::regtype);
<row>
<entry><literal><function>pg_get_viewdef(<parameter>view_name</parameter>)</function></literal></entry>
<entry><type>text</type></entry>
- <entry>get underlying <command>SELECT</command> command for view (<emphasis>deprecated</emphasis>)</entry>
+ <entry>get underlying <command>SELECT</command> command for view or materialized view (<emphasis>deprecated</emphasis>)</entry>
</row>
<row>
<entry><literal><function>pg_get_viewdef(<parameter>view_name</parameter>, <parameter>pretty_bool</>)</function></literal></entry>
<entry><type>text</type></entry>
- <entry>get underlying <command>SELECT</command> command for view (<emphasis>deprecated</emphasis>)</entry>
+ <entry>get underlying <command>SELECT</command> command for view or materialized view (<emphasis>deprecated</emphasis>)</entry>
</row>
<row>
<entry><literal><function>pg_get_viewdef(<parameter>view_oid</parameter>)</function></literal></entry>
<entry><type>text</type></entry>
- <entry>get underlying <command>SELECT</command> command for view</entry>
+ <entry>get underlying <command>SELECT</command> command for view or materialized view</entry>
</row>
<row>
<entry><literal><function>pg_get_viewdef(<parameter>view_oid</parameter>, <parameter>pretty_bool</>)</function></literal></entry>
<entry><type>text</type></entry>
- <entry>get underlying <command>SELECT</command> command for view</entry>
+ <entry>get underlying <command>SELECT</command> command for view or materialized view</entry>
</row>
<row>
<entry><literal><function>pg_get_viewdef(<parameter>view_oid</parameter>, <parameter>wrap_column_int</>)</function></literal></entry>
<entry><type>text</type></entry>
- <entry>get underlying <command>SELECT</command> command for view;
- lines with fields are wrapped to specified number of columns,
- pretty-printing is implied</entry>
+ <entry>get underlying <command>SELECT</command> command for view or
+ materialized view; lines with fields are wrapped to specified
+ number of columns, pretty-printing is implied</entry>
</row>
<row>
<entry><literal><function>pg_options_to_table(<parameter>reloptions</parameter>)</function></literal></entry>
@@ -13907,6 +13911,11 @@ SELECT pg_type_is_visible('myschema.widget'::regtype);
<entry>get the path in the file system that this tablespace is located in</entry>
</row>
<row>
+ <entry><literal><function>pg_relation_is_scannable(<parameter>relation_oid</parameter>)</function></literal></entry>
+ <entry><type>boolean</type></entry>
+ <entry>is the relation scannable; a materialized view which has not been loaded will not be scannable</entry>
+ </row>
+ <row>
<entry><literal><function>pg_typeof(<parameter>any</parameter>)</function></literal></entry>
<entry><type>regtype</type></entry>
<entry>get the data type of any value</entry>
View
4 doc/src/sgml/ref/allfiles.sgml
@@ -21,6 +21,7 @@ Complete list of usable sgml source files in this directory.
<!ENTITY alterIndex SYSTEM "alter_index.sgml">
<!ENTITY alterLanguage SYSTEM "alter_language.sgml">
<!ENTITY alterLargeObject SYSTEM "alter_large_object.sgml">
+<!ENTITY alterMaterializedView SYSTEM "alter_materialized_view.sgml">
<!ENTITY alterOperator SYSTEM "alter_operator.sgml">
<!ENTITY alterOperatorClass SYSTEM "alter_opclass.sgml">
<!ENTITY alterOperatorFamily SYSTEM "alter_opfamily.sgml">
@@ -63,6 +64,7 @@ Complete list of usable sgml source files in this directory.
<!ENTITY createGroup SYSTEM "create_group.sgml">
<!ENTITY createIndex SYSTEM "create_index.sgml">
<!ENTITY createLanguage SYSTEM "create_language.sgml">
+<!ENTITY createMaterializedView SYSTEM "create_materialized_view.sgml">
<!ENTITY createOperator SYSTEM "create_operator.sgml">
<!ENTITY createOperatorClass SYSTEM "create_opclass.sgml">
<!ENTITY createOperatorFamily SYSTEM "create_opfamily.sgml">
@@ -102,6 +104,7 @@ Complete list of usable sgml source files in this directory.
<!ENTITY dropGroup SYSTEM "drop_group.sgml">
<!ENTITY dropIndex SYSTEM "drop_index.sgml">
<!ENTITY dropLanguage SYSTEM "drop_language.sgml">
+<!ENTITY dropMaterializedView SYSTEM "drop_materialized_view.sgml">
<!ENTITY dropOperator SYSTEM "drop_operator.sgml">
<!ENTITY dropOperatorClass SYSTEM "drop_opclass.sgml">
<!ENTITY dropOperatorFamily SYSTEM "drop_opfamily.sgml">
@@ -136,6 +139,7 @@ Complete list of usable sgml source files in this directory.
<!ENTITY prepare SYSTEM "prepare.sgml">
<!ENTITY prepareTransaction SYSTEM "prepare_transaction.sgml">
<!ENTITY reassignOwned SYSTEM "reassign_owned.sgml">
+<!ENTITY refreshMaterializedView SYSTEM "refresh_materialized_view.sgml">
<!ENTITY reindex SYSTEM "reindex.sgml">
<!ENTITY releaseSavepoint SYSTEM "release_savepoint.sgml">
<!ENTITY reset SYSTEM "reset.sgml">
View
1  doc/src/sgml/ref/alter_extension.sgml
@@ -39,6 +39,7 @@ ALTER EXTENSION <replaceable class="PARAMETER">name</replaceable> DROP <replacea
FOREIGN DATA WRAPPER <replaceable class="PARAMETER">object_name</replaceable> |
FOREIGN TABLE <replaceable class="PARAMETER">object_name</replaceable> |
FUNCTION <replaceable class="PARAMETER">function_name</replaceable> ( [ [ <replaceable class="parameter">argmode</replaceable> ] [ <replaceable class="parameter">argname</replaceable> ] <replaceable class="parameter">argtype</replaceable> [, ...] ] ) |
+ MATERIALIZED VIEW <replaceable class="PARAMETER">object_name</replaceable> |
OPERATOR <replaceable class="PARAMETER">operator_name</replaceable> (<replaceable class="PARAMETER">left_type</replaceable>, <replaceable class="PARAMETER">right_type</replaceable>) |
OPERATOR CLASS <replaceable class="PARAMETER">object_name</replaceable> USING <replaceable class="parameter">index_method</replaceable> |
OPERATOR FAMILY <replaceable class="PARAMETER">object_name</replaceable> USING <replaceable class="parameter">index_method</replaceable> |
View
167 doc/src/sgml/ref/alter_materialized_view.sgml
@@ -0,0 +1,167 @@
+<!--
+doc/src/sgml/ref/alter_materialized_view.sgml
+PostgreSQL documentation
+-->
+
+<refentry id="SQL-ALTERMATERIALIZEDVIEW">
+ <refmeta>
+ <refentrytitle>ALTER MATERIALIZED VIEW</refentrytitle>
+ <manvolnum>7</manvolnum>
+ <refmiscinfo>SQL - Language Statements</refmiscinfo>
+ </refmeta>
+
+ <refnamediv>
+ <refname>ALTER MATERIALIZED VIEW</refname>
+ <refpurpose>change the definition of a materialized view</refpurpose>
+ </refnamediv>
+
+ <indexterm zone="sql-alterview">
+ <primary>ALTER MATERIALIZED VIEW</primary>
+ </indexterm>
+
+ <refsynopsisdiv>
+<synopsis>
+ALTER MATERIALIZED VIEW [ IF EXISTS ] <replaceable class="PARAMETER">name</replaceable>
+ <replaceable class="PARAMETER">action</replaceable> [, ... ]
+ALTER MATERIALIZED VIEW [ IF EXISTS ] <replaceable class="PARAMETER">name</replaceable>
+ RENAME [ COLUMN ] <replaceable class="PARAMETER">column_name</replaceable> TO <replaceable class="PARAMETER">new_column_name</replaceable>
+ALTER MATERIALIZED VIEW [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
+ RENAME TO <replaceable class="parameter">new_name</replaceable>
+ALTER MATERIALIZED VIEW [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
+ SET SCHEMA <replaceable class="parameter">new_schema</replaceable>
+
+<phrase>where <replaceable class="PARAMETER">action</replaceable> is one of:</phrase>
+
+ ALTER [ COLUMN ] <replaceable class="PARAMETER">column_name</replaceable> SET STATISTICS <replaceable class="PARAMETER">integer</replaceable>
+ ALTER [ COLUMN ] <replaceable class="PARAMETER">column_name</replaceable> SET ( <replaceable class="PARAMETER">attribute_option</replaceable> = <replaceable class="PARAMETER">value</replaceable> [, ... ] )
+ ALTER [ COLUMN ] <replaceable class="PARAMETER">column_name</replaceable> RESET ( <replaceable class="PARAMETER">attribute_option</replaceable> [, ... ] )
+ ALTER [ COLUMN ] <replaceable class="PARAMETER">column_name</replaceable> SET STORAGE { PLAIN | EXTERNAL | EXTENDED | MAIN }
+ CLUSTER ON <replaceable class="PARAMETER">index_name</replaceable>
+ SET WITHOUT CLUSTER
+ SET ( <replaceable class="PARAMETER">storage_parameter</replaceable> = <replaceable class="PARAMETER">value</replaceable> [, ... ] )
+ RESET ( <replaceable class="PARAMETER">storage_parameter</replaceable> [, ... ] )
+ OWNER TO <replaceable class="PARAMETER">new_owner</replaceable>
+ SET TABLESPACE <replaceable class="PARAMETER">new_tablespace</replaceable>
+</synopsis>
+ </refsynopsisdiv>
+
+ <refsect1>
+ <title>Description</title>
+
+ <para>
+ <command>ALTER MATERIALIZED VIEW</command> changes various auxiliary
+ properties of an existing materialized view.
+ </para>
+
+ <para>
+ You must own the materialized view to use <command>ALTER MATERIALIZED
+ VIEW</>. To change a materialized view's schema, you must also have
+ <literal>CREATE</> privilege on the new schema.
+ To alter the owner, you must also be a direct or indirect member of the new
+ owning role, and that role must have <literal>CREATE</literal> privilege on
+ the materialized view's schema. (These restrictions enforce that altering
+ the owner doesn't do anything you couldn't do by dropping and recreating the
+ materialized view. However, a superuser can alter ownership of any view
+ anyway.)
+ </para>
+
+ <para>
+ The statement subforms and actions available for
+ <command>ALTER MATERIALIZED VIEW</command> are a subset of those available
+ for <command>ALTER TABLE</command>, and have the same meaning when used for
+ materialized views. See the descriptions for <xref linkend="sql-altertable">
+ for details.
+ </para>
+ </refsect1>
+
+ <refsect1>
+ <title>Parameters</title>
+
+ <variablelist>
+
+ <varlistentry>
+ <term><replaceable class="parameter">name</replaceable></term>
+ <listitem>
+ <para>
+ The name (optionally schema-qualified) of an existing materialized view.
+ </para>
+ </listitem>
+ </varlistentry>
+
+ <varlistentry>
+ <term><replaceable class="PARAMETER">column_name</replaceable></term>
+ <listitem>
+ <para>
+ Name of a new or existing column.
+ </para>
+ </listitem>
+ </varlistentry>
+
+ <varlistentry>
+ <term><replaceable class="PARAMETER">new_column_name</replaceable></term>
+ <listitem>
+ <para>
+ New name for an existing column.
+ </para>
+ </listitem>
+ </varlistentry>
+
+ <varlistentry>
+ <term><replaceable class="PARAMETER">new_owner</replaceable></term>
+ <listitem>
+ <para>
+ The user name of the new owner of the materialized view.
+ </para>
+ </listitem>
+ </varlistentry>
+
+ <varlistentry>
+ <term><replaceable class="parameter">new_name</replaceable></term>
+ <listitem>
+ <para>
+ The new name for the materialized view.
+ </para>
+ </listitem>
+ </varlistentry>
+
+ <varlistentry>
+ <term><replaceable class="parameter">new_schema</replaceable></term>
+ <listitem>
+ <para>
+ The new schema for the materialized view.
+ </para>
+ </listitem>
+ </varlistentry>
+ </variablelist>
+ </refsect1>
+
+ <refsect1>
+ <title>Examples</title>
+
+ <para>
+ To rename the materialized view <literal>foo</literal> to
+ <literal>bar</literal>:
+<programlisting>
+ALTER MATERIALIZED VIEW foo RENAME TO bar;
+</programlisting></para>
+ </refsect1>
+
+ <refsect1>
+ <title>Compatibility</title>
+
+ <para>
+ <command>ALTER MATERIALIZED VIEW</command> is a
+ <productname>PostgreSQL</productname> extension.
+ </para>
+ </refsect1>
+
+ <refsect1>
+ <title>See Also</title>
+
+ <simplelist type="inline">
+ <member><xref linkend="sql-creatematerializedview"></member>
+ <member><xref linkend="sql-dropmaterializedview"></member>
+ <member><xref linkend="sql-refreshmaterializedview"></member>
+ </simplelist>
+ </refsect1>
+</refentry>
View
2  doc/src/sgml/ref/comment.sgml
@@ -38,6 +38,7 @@ COMMENT ON
FUNCTION <replaceable class="PARAMETER">function_name</replaceable> ( [ [ <replaceable class="parameter">argmode</replaceable> ] [ <replaceable class="parameter">argname</replaceable> ] <replaceable class="parameter">argtype</replaceable> [, ...] ] ) |
INDEX <replaceable class="PARAMETER">object_name</replaceable> |
LARGE OBJECT <replaceable class="PARAMETER">large_object_oid</replaceable> |
+ MATERIALIZED VIEW <replaceable class="PARAMETER">object_name</replaceable> |
OPERATOR <replaceable class="PARAMETER">operator_name</replaceable> (<replaceable class="PARAMETER">left_type</replaceable>, <replaceable class="PARAMETER">right_type</replaceable>) |
OPERATOR CLASS <replaceable class="PARAMETER">object_name</replaceable> USING <replaceable class="parameter">index_method</replaceable> |
OPERATOR FAMILY <replaceable class="PARAMETER">object_name</replaceable> USING <replaceable class="parameter">index_method</replaceable> |
@@ -279,6 +280,7 @@ COMMENT ON FUNCTION my_function (timestamp) IS 'Returns Roman Numeral';
COMMENT ON INDEX my_index IS 'Enforces uniqueness on employee ID';
COMMENT ON LANGUAGE plpython IS 'Python support for stored procedures';
COMMENT ON LARGE OBJECT 346344 IS 'Planning document';
+COMMENT ON MATERIALIZED VIEW my_matview IS 'Summary of order history';
COMMENT ON OPERATOR ^ (text, text) IS 'Performs intersection of two texts';
COMMENT ON OPERATOR - (NONE, integer) IS 'Unary minus';
COMMENT ON OPERATOR CLASS int4ops USING btree IS '4 byte integer operators for btrees';
View
4 doc/src/sgml/ref/create_index.sgml
@@ -33,8 +33,8 @@ CREATE [ UNIQUE ] INDEX [ CONCURRENTLY ] [ <replaceable class="parameter">name</
<title>Description</title>
<para>
- <command>CREATE INDEX</command> constructs an index
- on the specified column(s) of the specified table.
+ <command>CREATE INDEX</command> constructs an index on the specified column(s)
+ of the specified relation, which can be a table or a materialized view.
Indexes are primarily used to enhance database performance (though
inappropriate use can result in slower performance).
</para>
View
154 doc/src/sgml/ref/create_materialized_view.sgml
@@ -0,0 +1,154 @@
+<!--
+doc/src/sgml/ref/create_materialized_view.sgml
+PostgreSQL documentation
+-->
+
+<refentry id="SQL-CREATEMATERIALIZEDVIEW">
+ <refmeta>
+ <refentrytitle>CREATE MATERIALIZED VIEW</refentrytitle>
+ <manvolnum>7</manvolnum>
+ <refmiscinfo>SQL - Language Statements</refmiscinfo>
+ </refmeta>
+
+ <refnamediv>
+ <refname>CREATE MATERIALIZED VIEW</refname>
+ <refpurpose>define a new materialized view</refpurpose>
+ </refnamediv>
+
+ <indexterm zone="sql-creatematerializedview">
+ <primary>CREATE MATERIALIZED VIEW</primary>
+ </indexterm>
+
+ <refsynopsisdiv>
+<synopsis>
+CREATE [ UNLOGGED ] MATERIALIZED VIEW <replaceable>table_name</replaceable>
+ [ (<replaceable>column_name</replaceable> [, ...] ) ]
+ [ WITH ( <replaceable class="PARAMETER">storage_parameter</replaceable> [= <replaceable class="PARAMETER">value</replaceable>] [, ... ] ) ]
+ [ TABLESPACE <replaceable class="PARAMETER">tablespace_name</replaceable> ]
+ AS <replaceable>query</replaceable>
+ [ WITH [ NO ] DATA ]
+</synopsis>
+ </refsynopsisdiv>
+
+ <refsect1>
+ <title>Description</title>
+
+ <para>
+ <command>CREATE MATERIALIZED VIEW</command> defines a materialized view of
+ a query. The query is executed and used to populate the view at the time
+ the command is issued (unless <command>WITH NO DATA</> is used) and may be
+ refreshed later using <command>REFRESH MATERIALIZED VIEW</command>.
+ </para>
+
+ <para>
+ <command>CREATE MATERIALIZED VIEW</command> is similar to
+ <command>CREATE TABLE AS</>, except that it also remembers the query used
+ to initialize the view, so that it can be refreshed later upon demand.
+ </para>
+ </refsect1>
+
+ <refsect1>
+ <title>Parameters</title>
+
+ <variablelist>
+ <varlistentry>
+ <term><literal>UNLOGGED</></term>
+ <listitem>
+ <para>
+ If specified, the materialized view will be unlogged.
+ Refer to <xref linkend="sql-createtable"> for details.
+ </para>
+ </listitem>
+ </varlistentry>
+
+ <varlistentry>
+ <term><replaceable>table_name</replaceable></term>
+ <listitem>
+ <para>
+ The name (optionally schema-qualified) of the materialized view to be
+ created.
+ </para>
+ </listitem>
+ </varlistentry>
+
+ <varlistentry>
+ <term><replaceable>column_name</replaceable></term>
+ <listitem>
+ <para>
+ The name of a column in the new materialized view. If column names are
+ not provided, they are taken from the output column names of the query.
+ </para>
+ </listitem>
+ </varlistentry>
+
+ <varlistentry>
+ <term><literal>WITH ( <replaceable class="PARAMETER">storage_parameter</replaceable> [= <replaceable class="PARAMETER">value</replaceable>] [, ... ] )</literal></term>
+ <listitem>
+ <para>
+ This clause specifies optional storage parameters for the new
+ materialized view; see <xref linkend="sql-createtable-storage-parameters"
+ endterm="sql-createtable-storage-parameters-title"> for more
+ information.
+ See <xref linkend="sql-createtable"> for more information.
+ </para>
+ </listitem>
+ </varlistentry>
+
+ <varlistentry>
+ <term><literal>TABLESPACE <replaceable class="PARAMETER">tablespace_name</replaceable></literal></term>
+ <listitem>
+ <para>
+ The <replaceable class="PARAMETER">tablespace_name</replaceable> is the name
+ of the tablespace in which the new materialized view is to be created.
+ If not specified, <xref linkend="guc-default-tablespace"> is consulted.
+ </para>
+ </listitem>
+ </varlistentry>
+
+ <varlistentry>
+ <term><replaceable>query</replaceable></term>
+ <listitem>
+ <para>
+ A <xref linkend="sql-select">, <link linkend="sql-table">TABLE</link>,
+ or <xref linkend="sql-values"> command.
+ </para>
+ </listitem>
+ </varlistentry>
+
+ <varlistentry>
+ <term><literal>WITH [ NO ] DATA</></term>
+ <listitem>
+ <para>
+ This clause specifies whether or not the materialized view should be
+ populated at creation time. If not, the materialized view will be
+ flagged as unscannable and cannot be queried until <command>REFRESH
+ MATERIALIZED VIEW</> is used.
+ </para>
+ </listitem>
+ </varlistentry>
+
+ </variablelist>
+ </refsect1>
+
+ <refsect1>
+ <title>Compatibility</title>
+
+ <para>
+ <command>CREATE MATERIALIZED VIEW</command> is a
+ <productname>PostgreSQL</productname> extension.
+ </para>
+ </refsect1>
+
+ <refsect1>
+ <title>See Also</title>
+
+ <simplelist type="inline">
+ <member><xref linkend="sql-altermaterializedview"></member>
+ <member><xref linkend="sql-createtableas"></member>
+ <member><xref linkend="sql-createview"></member>
+ <member><xref linkend="sql-dropmaterializedview"></member>
+ <member><xref linkend="sql-refreshmaterializedview"></member>
+ </simplelist>
+ </refsect1>
+
+</refentry>
View
1  doc/src/sgml/ref/create_table_as.sgml
@@ -340,6 +340,7 @@ CREATE TEMP TABLE films_recent WITH (OIDS) ON COMMIT DROP AS
<title>See Also</title>
<simplelist type="inline">
+ <member><xref linkend="sql-creatematerializedview"></member>
<member><xref linkend="sql-createtable"></member>
<member><xref linkend="sql-execute"></member>
<member><xref linkend="sql-select"></member>
View
1  doc/src/sgml/ref/create_view.sgml
@@ -379,6 +379,7 @@ CREATE VIEW <replaceable class="parameter">name</replaceable> [ ( <replaceable c
<title>See Also</title>
<simplelist type="inline">
+ <member><xref linkend="sql-creatematerializedview"></member>
<member><xref linkend="sql-alterview"></member>
<member><xref linkend="sql-dropview"></member>
</simplelist>
View
114 doc/src/sgml/ref/drop_materialized_view.sgml
@@ -0,0 +1,114 @@
+<!--
+doc/src/sgml/ref/drop_materialized_view.sgml
+PostgreSQL documentation
+-->
+
+<refentry id="SQL-DROPMATERIALIZEDVIEW">
+ <refmeta>
+ <refentrytitle>DROP MATERIALIZED VIEW</refentrytitle>
+ <manvolnum>7</manvolnum>
+ <refmiscinfo>SQL - Language Statements</refmiscinfo>
+ </refmeta>
+
+ <refnamediv>
+ <refname>DROP MATERIALIZED VIEW</refname>
+ <refpurpose>remove a materialized view</refpurpose>
+ </refnamediv>
+
+ <indexterm zone="sql-dropmaterializedview">
+ <primary>DROP MATERIALIZED VIEW</primary>
+ </indexterm>
+
+ <refsynopsisdiv>
+<synopsis>
+DROP MATERIALIZED VIEW [ IF EXISTS ] <replaceable class="PARAMETER">name</replaceable> [, ...] [ CASCADE | RESTRICT ]
+</synopsis>
+ </refsynopsisdiv>
+
+ <refsect1>
+ <title>Description</title>
+
+ <para>
+ <command>DROP MATERIALIZED VIEW</command> drops an existing materialized
+ view. To execute this command you must be the owner of the materialized
+ view.
+ </para>
+ </refsect1>
+
+ <refsect1>
+ <title>Parameters</title>
+
+ <variablelist>
+ <varlistentry>
+ <term><literal>IF EXISTS</literal></term>
+ <listitem>
+ <para>
+ Do not throw an error if the materialized view does not exist. A notice
+ is issued in this case.
+ </para>
+ </listitem>
+ </varlistentry>
+
+ <varlistentry>
+ <term><replaceable class="PARAMETER">name</replaceable></term>
+ <listitem>
+ <para>
+ The name (optionally schema-qualified) of the materialized view to
+ remove.
+ </para>
+ </listitem>
+ </varlistentry>
+
+ <varlistentry>
+ <term><literal>CASCADE</literal></term>
+ <listitem>
+ <para>
+ Automatically drop objects that depend on the materialized view (such as
+ other materialized views, or regular views).
+ </para>
+ </listitem>
+ </varlistentry>
+
+ <varlistentry>
+ <term><literal>RESTRICT</literal></term>
+ <listitem>
+ <para>
+ Refuse to drop the materialized view if any objects depend on it. This
+ is the default.
+ </para>
+ </listitem>
+ </varlistentry>
+ </variablelist>
+ </refsect1>
+
+ <refsect1>
+ <title>Examples</title>
+
+ <para>
+ This command will remove the materialized view called
+ <literal>order_summary</literal>:
+<programlisting>
+DROP MATERIALIZED VIEW order_summary;
+</programlisting></para>
+ </refsect1>
+
+ <refsect1>
+ <title>Compatibility</title>
+
+ <para>
+ <command>DROP MATERIALIZED VIEW</command> is a
+ <productname>PostgreSQL</productname> extension.
+ </para>
+ </refsect1>
+
+ <refsect1>
+ <title>See Also</title>
+
+ <simplelist type="inline">
+ <member><xref linkend="sql-creatematerializedview"></member>
+ <member><xref linkend="sql-altermaterializedview"></member>
+ <member><xref linkend="sql-refreshmaterializedview"></member>
+ </simplelist>
+ </refsect1>
+
+</refentry>
View
113 doc/src/sgml/ref/refresh_materialized_view.sgml
@@ -0,0 +1,113 @@
+<!--
+doc/src/sgml/ref/refresh_materialized_view.sgml
+PostgreSQL documentation
+-->
+
+<refentry id="SQL-REFRESHMATERIALIZEDVIEW">
+ <refmeta>
+ <refentrytitle>REFRESH MATERIALIZED VIEW</refentrytitle>
+ <manvolnum>7</manvolnum>
+ <refmiscinfo>SQL - Language Statements</refmiscinfo>
+ </refmeta>
+
+ <refnamediv>
+ <refname>REFRESH MATERIALIZED VIEW</refname>
+ <refpurpose>replace the contents of a materialized view</refpurpose>
+ </refnamediv>
+
+ <indexterm zone="sql-refreshmaterializedview">
+ <primary>REFRESH MATERIALIZED VIEW</primary>
+ </indexterm>
+
+ <refsynopsisdiv>
+<synopsis>
+REFRESH MATERIALIZED VIEW <replaceable class="PARAMETER">name</replaceable>
+ [ WITH [ NO ] DATA ]
+</synopsis>
+ </refsynopsisdiv>
+
+ <refsect1>
+ <title>Description</title>
+
+ <para>
+ <command>REFRESH MATERIALIZED VIEW</command> completely replaces the
+ contents of a materialized view. The old contents are discarded. If
+ <literal>WITH DATA</literal> is specified (or defaults) the backing query
+ is executed to provide the new data, and the materialized view is left in a
+ scannable state. If <literal>WITH NO DATA</literal> is specified no new
+ data is generated and the materialized view is left in an unscannable
+ state.
+ </para>
+ </refsect1>
+
+ <refsect1>
+ <title>Parameters</title>
+
+ <variablelist>
+ <varlistentry>
+ <term><replaceable class="PARAMETER">name</replaceable></term>
+ <listitem>
+ <para>
+ The name (optionally schema-qualified) of the materialized view to
+ refresh.
+ </para>
+ </listitem>
+ </varlistentry>
+ </variablelist>
+ </refsect1>
+
+ <refsect1>
+ <title>Notes</title>
+
+ <para>
+ While the default index for future
+ <xref linkend="SQL-CLUSTER">
+ operations is retained, <command>REFRESH MATERIALIZED VIEW</> does not
+ order the generated rows based on this property. If you want the data
+ to be ordered upon generation, you must use an <literal>ORDER BY</>
+ clause in the backing query.
+ </para>
+ </refsect1>
+
+ <refsect1>
+ <title>Examples</title>
+
+ <para>
+ This command will replace the contents of the materialized view called
+ <literal>order_summary</literal> using the query from the materialized
+ view's definition, and leave it in a scannable state:
+<programlisting>
+REFRESH MATERIALIZED VIEW order_summary;
+</programlisting>
+ </para>
+
+ <para>
+ This command will free storage associated with the materialized view
+ <literal>annual_statistics_basis</literal> and leave it in an unscannable
+ state:
+<programlisting>
+REFRESH MATERIALIZED VIEW annual_statistics_basis WITH NO DATA;
+</programlisting>
+ </para>
+ </refsect1>
+
+ <refsect1>
+ <title>Compatibility</title>
+
+ <para>
+ <command>REFRESH MATERIALIZED VIEW</command> is a
+ <productname>PostgreSQL</productname> extension.
+ </para>
+ </refsect1>
+
+ <refsect1>
+ <title>See Also</title>
+
+ <simplelist type="inline">
+ <member><xref linkend="sql-creatematerializedview"></member>
+ <member><xref linkend="sql-altermaterializedview"></member>
+ <member><xref linkend="sql-dropmaterializedview"></member>
+ </simplelist>
+ </refsect1>
+
+</refentry>
View
1  doc/src/sgml/ref/security_label.sgml
@@ -32,6 +32,7 @@ SECURITY LABEL [ FOR <replaceable class="PARAMETER">provider</replaceable> ] ON
FOREIGN TABLE <replaceable class="PARAMETER">object_name</replaceable>
FUNCTION <replaceable class="PARAMETER">function_name</replaceable> ( [ [ <replaceable class="parameter">argmode</replaceable> ] [ <replaceable class="parameter">argname</replaceable> ] <replaceable class="parameter">argtype</replaceable> [, ...] ] ) |
LARGE OBJECT <replaceable class="PARAMETER">large_object_oid</replaceable> |
+ MATERIALIZED VIEW <replaceable class="PARAMETER">object_name</replaceable> |
[ PROCEDURAL ] LANGUAGE <replaceable class="PARAMETER">object_name</replaceable> |
ROLE <replaceable class="PARAMETER">object_name</replaceable> |
SCHEMA <replaceable class="PARAMETER">object_name</replaceable> |
View
4 doc/src/sgml/reference.sgml
@@ -49,6 +49,7 @@
&alterIndex;
&alterLanguage;
&alterLargeObject;
+ &alterMaterializedView;
&alterOperator;
&alterOperatorClass;
&alterOperatorFamily;
@@ -91,6 +92,7 @@
&createGroup;
&createIndex;
&createLanguage;
+ &createMaterializedView;
&createOperator;
&createOperatorClass;
&createOperatorFamily;
@@ -130,6 +132,7 @@
&dropGroup;
&dropIndex;
&dropLanguage;
+ &dropMaterializedView;
&dropOperator;
&dropOperatorClass;
&dropOperatorFamily;
@@ -164,6 +167,7 @@
&prepare;
&prepareTransaction;
&reassignOwned;
+ &refreshMaterializedView;
&reindex;
&releaseSavepoint;
&reset;
View
200 doc/src/sgml/rules.sgml
@@ -893,6 +893,206 @@ SELECT t1.a, t2.b, t1.ctid FROM t1, t2 WHERE t1.a = t2.a;
</sect1>
+<sect1 id="rules-materializedviews">
+<title>Materialized Views</title>
+
+<indexterm zone="rules-materializedviews">
+ <primary>rule</primary>
+ <secondary>and materialized views</secondary>
+</indexterm>
+
+<indexterm zone="rules-materializedviews">
+ <primary>materialized view</>
+ <secondary>implementation through rules</>
+</indexterm>
+
+<indexterm zone="rules-materializedviews">
+ <primary>view</>
+ <secondary>materialized</>
+</indexterm>
+
+<para>
+ Materialized views in <productname>PostgreSQL</productname> use the
+ rule system like views do, but persist the results in a table-like form.
+ The main differences between:
+
+<programlisting>
+CREATE MATERIALIZED VIEW mymatview AS SELECT * FROM mytab;
+</programlisting>
+
+ and:
+
+<programlisting>
+CREATE TABLE mymatview AS SELECT * FROM mytab;
+</programlisting>
+
+ are that the materialized view cannot subsequently be directly updated
+ and that the query used to create the materialized view is stored in
+ exactly the same way that a view's query is stored, so that fresh data
+ can be generated for the materialized view with:
+
+<programlisting>
+REFRESH MATERIALIZED VIEW mymatview;
+</programlisting>
+
+ The information about a materialized view in the
+ <productname>PostgreSQL</productname> system catalogs is exactly
+ the same as it is for a table or view. So for the parser, a
+ materialized view is a relation, just like a table or a view. When
+ a materialized view is referenced in a query, the data is returned
+ directly from the materialized view, like from a table; the rule is
+ only used for populating the materialized view.
+</para>
+
+<para>
+ While access to the data stored in a materialized view is often much
+ faster than accessing the underlying tables directly or through a view,
+ the data is not always current; yet sometimes current data is not needed.
+ Consider a table which records sales:
+
+<programlisting>
+CREATE TABLE invoice (
+ invoice_no integer PRIMARY KEY,
+ seller_no integer, -- ID of salesperson
+ invoice_date date, -- date of sale
+ invoice_amt numeric(13,2) -- amount of sale
+);
+</programlisting>
+
+ If people want to be able to quickly graph historical sales data, they
+ might want to summarize, and they may not care about the incomplete data
+ for the current date:
+
+<programlisting>
+CREATE MATERIALIZED VIEW sales_summary AS
+ SELECT
+ seller_no,
+ invoice_date,
+ sum(invoice_amt)::numeric(13,2) as sales_amt
+ FROM invoice
+ WHERE invoice_date < CURRENT_DATE
+ GROUP BY
+ seller_no,
+ invoice_date
+ ORDER BY
+ seller_no,
+ invoice_date;
+
+CREATE UNIQUE INDEX sales_summary_seller
+ ON sales_summary (seller_no, invoice_date);
+</programlisting>
+
+ This materialized view might be useful for displaying a graph in the
+ dashboard created for salespeople. A job could be scheduled to update
+ the statistics each night using this SQL statement:
+
+<programlisting>
+REFRESH MATERIALIZED VIEW sales_summary;
+</programlisting>
+</para>
+
+<para>
+ Another use for a materialized view is to allow faster access to data
+ brought across from a remote system, through a foreign data wrapper.
+ A simple example using <literal>file_fdw</literal> is below, with timings,
+ but since this is using cache on the local system the performance
+ difference on a foreign data wrapper to a remote system could be greater.
+
+ Setup:
+
+<programlisting>
+CREATE EXTENSION file_fdw;
+CREATE SERVER local_file FOREIGN DATA WRAPPER file_fdw ;
+CREATE FOREIGN TABLE words (word text NOT NULL)
+ SERVER local_file
+ OPTIONS (filename '/etc/dictionaries-common/words');
+CREATE MATERIALIZED VIEW wrd AS SELECT * FROM words;
+CREATE UNIQUE INDEX wrd_word ON wrd (word);
+CREATE EXTENSION pg_trgm ;
+CREATE INDEX wrd_trgm ON wrd USING gist (word gist_trgm_ops);
+VACUUM ANALYZE wrd;
+</programlisting>
+
+ Now let's spell-check a word. Using <literal>file_fdw</literal> directly:
+
+<programlisting>
+SELECT count(*) FROM words WHERE word = 'caterpiler';
+
+ count
+-------
+ 0
+(1 row)
+</programlisting>
+
+ The plan is:
+
+<programlisting>
+ Aggregate (cost=4125.19..4125.20 rows=1 width=0) (actual time=26.013..26.014 rows=1 loops=1)
+ -> Foreign Scan on words (cost=0.00..4124.70 rows=196 width=0) (actual time=26.011..26.011 rows=0 loops=1)
+ Filter: (word = 'caterpiler'::text)
+ Rows Removed by Filter: 99171
+ Foreign File: /etc/dictionaries-common/words
+ Foreign File Size: 938848
+ Total runtime: 26.081 ms
+</programlisting>
+
+ If the materialized view is used instead, the query is much faster:
+
+<programlisting>
+ Aggregate (cost=4.44..4.45 rows=1 width=0) (actual time=0.074..0.074 rows=1 loops=1)
+ -> Index Only Scan using wrd_word on wrd (cost=0.42..4.44 rows=1 width=0) (actual time=0.071..0.071 rows=0 loops=1)
+ Index Cond: (word = 'caterpiler'::text)
+ Heap Fetches: 0
+ Total runtime: 0.119 ms
+</programlisting>
+
+ Either way, the word is spelled wrong, so let's look for what we might
+ have wanted. Again using <literal>file_fdw</literal>:
+
+<programlisting>
+SELECT word FROM words ORDER BY word <-> 'caterpiler' LIMIT 10;
+
+ word
+---------------
+ cater
+ caterpillar
+ Caterpillar
+ caterpillars
+ caterpillar's
+ Caterpillar's
+ caterer
+ caterer's
+ caters
+ catered
+(10 rows)
+</programlisting>
+
+<programlisting>
+ Limit (cost=2195.70..2195.72 rows=10 width=32) (actual time=218.904..218.906 rows=10 loops=1)
+ -> Sort (cost=2195.70..2237.61 rows=16765 width=32) (actual time=218.902..218.904 rows=10 loops=1)
+ Sort Key: ((word <-> 'caterpiler'::text))
+ Sort Method: top-N heapsort Memory: 25kB
+ -> Foreign Scan on words (cost=0.00..1833.41 rows=16765 width=32) (actual time=0.046..200.965 rows=99171 loops=1)
+ Foreign File: /etc/dictionaries-common/words
+ Foreign File Size: 938848
+ Total runtime: 218.966 ms
+</programlisting>
+
+ Using the materialized view:
+
+<programlisting>
+ Limit (cost=0.28..1.02 rows=10 width=9) (actual time=24.916..25.079 rows=10 loops=1)
+ -> Index Scan using wrd_trgm on wrd (cost=0.28..7383.70 rows=99171 width=9) (actual time=24.914..25.076 rows=10 loops=1)
+ Order By: (word <-> 'caterpiler'::text)
+ Total runtime: 25.884 ms
+</programlisting>
+
+ If you can tolerate periodic update of the remote data to the local
+ database, the performance benefit can be substantial.
+</para>
+
+</sect1>
+
<sect1 id="rules-update">
<title>Rules on <command>INSERT</>, <command>UPDATE</>, and <command>DELETE</></title>
View
2  src/backend/access/common/reloptions.c
@@ -791,6 +791,7 @@ extractRelOptions(HeapTuple tuple, TupleDesc tupdesc, Oid amoptions)
case RELKIND_RELATION:
case RELKIND_TOASTVALUE:
case RELKIND_VIEW:
+ case RELKIND_MATVIEW:
options = heap_reloptions(classForm->relkind, datum, false);
break;
case RELKIND_INDEX:
@@ -1191,6 +1192,7 @@ heap_reloptions(char relkind, Datum reloptions, bool validate)
}
return (bytea *) rdopts;
case RELKIND_RELATION:
+ case RELKIND_MATVIEW:
return default_reloptions(reloptions, validate, RELOPT_KIND_HEAP);
case RELKIND_VIEW:
return default_reloptions(reloptions, validate, RELOPT_KIND_VIEW);
View
9 src/backend/access/heap/heapam.c
@@ -2214,7 +2214,8 @@ heap_prepare_insert(Relation relation, HeapTuple tup, TransactionId xid,
* If the new tuple is too big for storage or contains already toasted
* out-of-line attributes from some other relation, invoke the toaster.
*/
- if (relation->rd_rel->relkind != RELKIND_RELATION)
+ if (relation->rd_rel->relkind != RELKIND_RELATION &&
+ relation->rd_rel->relkind != RELKIND_MATVIEW)
{
/* toast table entries should never be recursively toasted */
Assert(!HeapTupleHasExternal(tup));
@@ -2802,7 +2803,8 @@ heap_delete(Relation relation, ItemPointer tid,
* because we need to look at the contents of the tuple, but it's OK to
* release the content lock on the buffer first.
*/
- if (relation->rd_rel->relkind != RELKIND_RELATION)
+ if (relation->rd_rel->relkind != RELKIND_RELATION &&
+ relation->rd_rel->relkind != RELKIND_MATVIEW)
{
/* toast table entries should never be recursively toasted */
Assert(!HeapTupleHasExternal(&tp));
@@ -3346,7 +3348,8 @@ heap_update(Relation relation, ItemPointer otid, HeapTuple newtup,
* We need to invoke the toaster if there are already any out-of-line
* toasted values present, or if the new tuple is over-threshold.
*/
- if (relation->rd_rel->relkind != RELKIND_RELATION)
+ if (relation->rd_rel->relkind != RELKIND_RELATION &&
+ relation->rd_rel->relkind != RELKIND_MATVIEW)
{
/* toast table entries should never be recursively toasted */
Assert(!HeapTupleHasExternal(&oldtup));
View
10 src/backend/access/heap/tuptoaster.c
@@ -353,10 +353,11 @@ toast_delete(Relation rel, HeapTuple oldtup)
bool toast_isnull[MaxHeapAttributeNumber];
/*
- * We should only ever be called for tuples of plain relations ---
- * recursing on a toast rel is bad news.
+ * We should only ever be called for tuples of plain relations or
+ * materialized views --- recursing on a toast rel is bad news.
*/
- Assert(rel->rd_rel->relkind == RELKIND_RELATION);
+ Assert(rel->rd_rel->relkind == RELKIND_RELATION ||
+ rel->rd_rel->relkind == RELKIND_MATVIEW);
/*
* Get the tuple descriptor and break down the tuple into fields.
@@ -443,7 +444,8 @@ toast_insert_or_update(Relation rel, HeapTuple newtup, HeapTuple oldtup,
* We should only ever be called for tuples of plain relations ---
* recursing on a toast rel is bad news.
*/
- Assert(rel->rd_rel->relkind == RELKIND_RELATION);
+ Assert(rel->rd_rel->relkind == RELKIND_RELATION ||
+ rel->rd_rel->relkind == RELKIND_MATVIEW);
/*
* Get the tuple descriptor and break down the tuple(s) into fields.
View
2  src/backend/catalog/aclchk.c
@@ -765,6 +765,8 @@ objectsInSchemaToOids(GrantObjectType objtype, List *nspnames)
objects = list_concat(objects, objs);
objs = getRelationsInNamespace(namespaceId, RELKIND_VIEW);
objects = list_concat(objects, objs);
+ objs = getRelationsInNamespace(namespaceId, RELKIND_MATVIEW);
+ objects = list_concat(objects, objs);
objs = getRelationsInNamespace(namespaceId, RELKIND_FOREIGN_TABLE);
objects = list_concat(objects, objs);
break;
View
4 src/backend/catalog/dependency.c
@@ -3024,6 +3024,10 @@ getRelationDescription(StringInfo buffer, Oid relid)
appendStringInfo(buffer, _("view %s"),
relname);
break;
+ case RELKIND_MATVIEW:
+ appendStringInfo(buffer, _("materialized view %s"),
+ relname);
+ break;
case RELKIND_COMPOSITE_TYPE:
appendStringInfo(buffer, _("composite type %s"),
relname);
View
31 src/backend/catalog/heap.c
@@ -835,6 +835,7 @@ AddNewRelationTuple(Relation pg_class_desc,
switch (relkind)
{
case RELKIND_RELATION:
+ case RELKIND_MATVIEW:
case RELKIND_INDEX:
case RELKIND_TOASTVALUE:
/* The relation is real, but as yet empty */
@@ -858,6 +859,7 @@ AddNewRelationTuple(Relation pg_class_desc,
/* Initialize relfrozenxid and relminmxid */
if (relkind == RELKIND_RELATION ||
+ relkind == RELKIND_MATVIEW ||
relkind == RELKIND_TOASTVALUE)
{
/*
@@ -1069,8 +1071,8 @@ heap_create_with_catalog(const char *relname,
if (IsBinaryUpgrade &&
OidIsValid(binary_upgrade_next_heap_pg_class_oid) &&
(relkind == RELKIND_RELATION || relkind == RELKIND_SEQUENCE ||
- relkind == RELKIND_VIEW || relkind == RELKIND_COMPOSITE_TYPE ||
- relkind == RELKIND_FOREIGN_TABLE))
+ relkind == RELKIND_VIEW || relkind == RELKIND_MATVIEW ||
+ relkind == RELKIND_COMPOSITE_TYPE || relkind == RELKIND_FOREIGN_TABLE))
{
relid = binary_upgrade_next_heap_pg_class_oid;
binary_upgrade_next_heap_pg_class_oid = InvalidOid;
@@ -1096,6 +1098,7 @@ heap_create_with_catalog(const char *relname,
{
case RELKIND_RELATION:
case RELKIND_VIEW:
+ case RELKIND_MATVIEW:
case RELKIND_FOREIGN_TABLE:
relacl = get_user_default_acl(ACL_OBJECT_RELATION, ownerid,
relnamespace);
@@ -1139,6 +1142,7 @@ heap_create_with_catalog(const char *relname,
*/
if (IsUnderPostmaster && (relkind == RELKIND_RELATION ||
relkind == RELKIND_VIEW ||
+ relkind == RELKIND_MATVIEW ||
relkind == RELKIND_FOREIGN_TABLE ||
relkind == RELKIND_COMPOSITE_TYPE))
new_array_oid = AssignTypeArrayOid();
@@ -1316,7 +1320,8 @@ heap_create_with_catalog(const char *relname,
if (relpersistence == RELPERSISTENCE_UNLOGGED)
{
- Assert(relkind == RELKIND_RELATION || relkind == RELKIND_TOASTVALUE);
+ Assert(relkind == RELKIND_RELATION || relkind == RELKIND_MATVIEW ||
+ relkind == RELKIND_TOASTVALUE);
heap_create_init_fork(new_rel_desc);
}
@@ -1348,6 +1353,26 @@ heap_create_init_fork(Relation rel)
}
/*
+ * Check whether a materialized view is in an initial, unloaded state.
+ *
+ * The check here must match what is set up in heap_create_init_fork().
+ * Currently the init fork is an empty file. A missing heap is also
+ * considered to be unloaded.
+ */
+bool
+heap_is_matview_init_state(Relation rel)
+{
+ Assert(rel->rd_rel->relkind == RELKIND_MATVIEW);
+
+ RelationOpenSmgr(rel);
+
+ if (!smgrexists(rel->rd_smgr, MAIN_FORKNUM))
+ return true;
+
+ return (smgrnblocks(rel->rd_smgr, MAIN_FORKNUM) < 1);
+}
+
+/*
* RelationRemoveInheritance
*
* Formerly, this routine checked for child relations and aborted the
View
9 src/backend/catalog/objectaddress.c
@@ -444,6 +444,7 @@ get_object_address(ObjectType objtype, List *objname, List *objargs,
case OBJECT_SEQUENCE:
case OBJECT_TABLE:
case OBJECT_VIEW:
+ case OBJECT_MATVIEW:
case OBJECT_FOREIGN_TABLE:
address =
get_relation_by_qualified_name(objtype, objname,
@@ -816,6 +817,13 @@ get_relation_by_qualified_name(ObjectType objtype, List *objname,
errmsg("\"%s\" is not a view",
RelationGetRelationName(relation))));
break;
+ case OBJECT_MATVIEW:
+ if (relation->rd_rel->relkind != RELKIND_MATVIEW)
+ ereport(ERROR,
+ (errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("\"%s\" is not a materialized view",
+ RelationGetRelationName(relation))));
+ break;
case OBJECT_FOREIGN_TABLE:
if (relation->rd_rel->relkind != RELKIND_FOREIGN_TABLE)
ereport(ERROR,
@@ -1073,6 +1081,7 @@ check_object_ownership(Oid roleid, ObjectType objtype, ObjectAddress address,
case OBJECT_SEQUENCE:
case OBJECT_TABLE:
case OBJECT_VIEW:
+ case OBJECT_MATVIEW:
case OBJECT_FOREIGN_TABLE:
case OBJECT_COLUMN:
case OBJECT_RULE:
View
26 src/backend/catalog/system_views.sql
@@ -94,6 +94,19 @@ CREATE VIEW pg_tables AS
LEFT JOIN pg_tablespace T ON (T.oid = C.reltablespace)
WHERE C.relkind = 'r';
+CREATE VIEW pg_matviews AS
+ SELECT
+ N.nspname AS schemaname,
+ C.relname AS matviewname,
+ pg_get_userbyid(C.relowner) AS matviewowner,
+ T.spcname AS tablespace,
+ C.relhasindex AS hasindexes,
+ pg_relation_is_scannable(C.oid) AS isscannable,
+ pg_get_viewdef(C.oid) AS definition
+ FROM pg_class C LEFT JOIN pg_namespace N ON (N.oid = C.relnamespace)
+ LEFT JOIN pg_tablespace T ON (T.oid = C.reltablespace)
+ WHERE C.relkind = 'm';
+
CREATE VIEW pg_indexes AS
SELECT
N.nspname AS schemaname,
@@ -105,7 +118,7 @@ CREATE VIEW pg_indexes AS
JOIN pg_class I ON (I.oid = X.indexrelid)
LEFT JOIN pg_namespace N ON (N.oid = C.relnamespace)
LEFT JOIN pg_tablespace T ON (T.oid = I.reltablespace)
- WHERE C.relkind = 'r' AND I.relkind = 'i';
+ WHERE C.relkind IN ('r', 'm') AND I.relkind = 'i';
CREATE VIEW pg_stats AS
SELECT
@@ -206,6 +219,7 @@ SELECT
l.objoid, l.classoid, l.objsubid,
CASE WHEN rel.relkind = 'r' THEN 'table'::text
WHEN rel.relkind = 'v' THEN 'view'::text
+ WHEN rel.relkind = 'm' THEN 'materialized view'::text
WHEN rel.relkind = 'S' THEN 'sequence'::text
WHEN rel.relkind = 'f' THEN 'foreign table'::text END AS objtype,
rel.relnamespace AS objnamespace,
@@ -402,7 +416,7 @@ CREATE VIEW pg_stat_all_tables AS
FROM pg_class C LEFT JOIN
pg_index I ON C.oid = I.indrelid
LEFT JOIN pg_namespace N ON (N.oid = C.relnamespace)
- WHERE C.relkind IN ('r', 't')
+ WHERE C.relkind IN ('r', 't', 'm')
GROUP BY C.oid, N.nspname, C.relname;
CREATE VIEW pg_stat_xact_all_tables AS
@@ -422,7 +436,7 @@ CREATE VIEW pg_stat_xact_all_tables AS
FROM pg_class C LEFT JOIN
pg_index I ON C.oid = I.indrelid
LEFT JOIN pg_namespace N ON (N.oid = C.relnamespace)
- WHERE C.relkind IN ('r', 't')
+ WHERE C.relkind IN ('r', 't', 'm')
GROUP BY C.oid, N.nspname, C.relname;
CREATE VIEW pg_stat_sys_tables AS
@@ -467,7 +481,7 @@ CREATE VIEW pg_statio_all_tables AS
pg_class T ON C.reltoastrelid = T.oid LEFT JOIN
pg_class X ON T.reltoastidxid = X.oid
LEFT JOIN pg_namespace N ON (N.oid = C.relnamespace)
- WHERE C.relkind IN ('r', 't')
+ WHERE C.relkind IN ('r', 't', 'm')
GROUP BY C.oid, N.nspname, C.relname, T.oid, X.oid;
CREATE VIEW pg_statio_sys_tables AS
@@ -494,7 +508,7 @@ CREATE VIEW pg_stat_all_indexes AS
pg_index X ON C.oid = X.indrelid JOIN
pg_class I ON I.oid = X.indexrelid
LEFT JOIN pg_namespace N ON (N.oid = C.relnamespace)
- WHERE C.relkind IN ('r', 't');
+ WHERE C.relkind IN ('r', 't', 'm');
CREATE VIEW pg_stat_sys_indexes AS
SELECT * FROM pg_stat_all_indexes
@@ -520,7 +534,7 @@ CREATE VIEW pg_statio_all_indexes AS
pg_index X ON C.oid = X.indrelid JOIN
pg_class I ON I.oid = X.indexrelid
LEFT JOIN pg_namespace N ON (N.oid = C.relnamespace)
- WHERE C.relkind IN ('r', 't');
+ WHERE C.relkind IN ('r', 't', 'm');
CREATE VIEW pg_statio_sys_indexes AS
SELECT * FROM pg_statio_all_indexes
View
5 src/backend/catalog/toasting.c
@@ -84,10 +84,11 @@ BootstrapToastTable(char *relName, Oid toastOid, Oid toastIndexOid)
rel = heap_openrv(makeRangeVar(NULL, relName, -1), AccessExclusiveLock);
- if (rel->rd_rel->relkind != RELKIND_RELATION)
+ if (rel->rd_rel->relkind != RELKIND_RELATION &&
+ rel->rd_rel->relkind != RELKIND_MATVIEW)
ereport(ERROR,
(errcode(ERRCODE_WRONG_OBJECT_TYPE),
- errmsg("\"%s\" is not a table",
+ errmsg("\"%s\" is not a table or materialized view",
relName)));
/* create_toast_table does all the work */
View
2  src/backend/commands/Makefile
@@ -16,7 +16,7 @@ OBJS = aggregatecmds.o alter.o analyze.o async.o cluster.o comment.o \
collationcmds.o constraint.o conversioncmds.o copy.o createas.o \
dbcommands.o define.o discard.o dropcmds.o \
event_trigger.o explain.o extension.o foreigncmds.o functioncmds.o \
- indexcmds.o lockcmds.o operatorcmds.o opclasscmds.o \
+ indexcmds.o lockcmds.o matview.o operatorcmds.o opclasscmds.o \
portalcmds.o prepare.o proclang.o \
schemacmds.o seclabel.o sequence.o tablecmds.o tablespace.o trigger.o \
tsearchcmds.o typecmds.o user.o vacuum.o vacuumlazy.o \
View
2  src/backend/commands/alter.c
@@ -317,6 +317,7 @@ ExecRenameStmt(RenameStmt *stmt)
case OBJECT_TABLE:
case OBJECT_SEQUENCE:
case OBJECT_VIEW:
+ case OBJECT_MATVIEW:
case OBJECT_INDEX:
case OBJECT_FOREIGN_TABLE:
return RenameRelation(stmt);
@@ -393,6 +394,7 @@ ExecAlterObjectSchemaStmt(AlterObjectSchemaStmt *stmt)
case OBJECT_SEQUENCE:
case OBJECT_TABLE:
case OBJECT_VIEW:
+ case OBJECT_MATVIEW:
return AlterTableNamespace(stmt);
case OBJECT_DOMAIN:
View
9 src/backend/commands/analyze.c
@@ -206,11 +206,12 @@ analyze_rel(Oid relid, VacuumStmt *vacstmt, BufferAccessStrategy bstrategy)
}
/*
- * Check that it's a plain table or foreign table; we used to do this in
- * get_rel_oids() but seems safer to check after we've locked the
- * relation.
+ * Check that it's a plain table, materialized view, or foreign table; we
+ * used to do this in get_rel_oids() but seems safer to check after we've
+ * locked the relation.
*/
- if (onerel->rd_rel->relkind == RELKIND_RELATION)
+ if (onerel->rd_rel->relkind == RELKIND_RELATION ||
+ onerel->rd_rel->relkind == RELKIND_MATVIEW)
{
/* Regular table, so we'll use the regular row acquisition function */
acquirefunc = acquire_sample_rows;
View
18 src/backend/commands/cluster.c
@@ -29,6 +29,7 @@
#include "catalog/namespace.h"
#include "catalog/toasting.h"
#include "commands/cluster.h"
+#include "commands/matview.h"
#include "commands/tablecmds.h"
#include "commands/vacuum.h"
#include "miscadmin.h"
@@ -379,6 +380,19 @@ cluster_rel(Oid tableOid, Oid indexOid, bool recheck, bool verbose,
check_index_is_clusterable(OldHeap, indexOid, recheck, AccessExclusiveLock);
/*
+ * Quietly ignore the request if the a materialized view is not scannable.
+ * No harm is done because there is nothing no data to deal with, and we
+ * don't want to throw an error if this is part of a multi-relation
+ * request -- for example, CLUSTER was run on the entire database.
+ */
+ if (OldHeap->rd_rel->relkind == RELKIND_MATVIEW &&
+ !OldHeap->rd_isscannable)
+ {
+ relation_close(OldHeap, AccessExclusiveLock);
+ return;
+ }
+
+ /*
* All predicate locks on the tuples or pages are about to be made
* invalid, because we move tuples around. Promote them to relation
* locks. Predicate locks on indexes will be promoted when they are
@@ -901,6 +915,10 @@ copy_heap_data(Oid OIDNewHeap, Oid OIDOldHeap, Oid OIDOldIndex,
get_namespace_name(RelationGetNamespace(OldHeap)),
RelationGetRelationName(OldHeap))));
+ if (OldHeap->rd_rel->relkind == RELKIND_MATVIEW)
+ /* Make sure the heap looks good even if no rows are written. */
+ SetRelationIsScannable(NewHeap);
+
/*
* Scan through the OldHeap, either in OldIndex order or sequentially;
* copy each tuple into the NewHeap, or transiently to the tuplesort
View
14 src/backend/commands/comment.c
@@ -83,15 +83,17 @@ CommentObject(CommentStmt *stmt)
case OBJECT_COLUMN:
/*
- * Allow comments only on columns of tables, views, composite
- * types, and foreign tables (which are the only relkinds for
- * which pg_dump will dump per-column comments). In particular we
- * wish to disallow comments on index columns, because the naming
- * of an index's columns may change across PG versions, so dumping
- * per-column comments could create reload failures.
+ * Allow comments only on columns of tables, views, materialized
+ * views, composite types, and foreign tables (which are the only
+ * relkinds for which pg_dump will dump per-column comments). In
+ * particular we wish to disallow comments on index columns,
+ * because the naming of an index's columns may change across PG
+ * versions, so dumping per-column comments could create reload
+ * failures.
*/
if (relation->rd_rel->relkind != RELKIND_RELATION &&
relation->rd_rel->relkind != RELKIND_VIEW &&
+ relation->rd_rel->relkind != RELKIND_MATVIEW &&
relation->rd_rel->relkind != RELKIND_COMPOSITE_TYPE &&
relation->rd_rel->relkind != RELKIND_FOREIGN_TABLE)
ereport(ERROR,
View
11 src/backend/commands/copy.c
@@ -1496,6 +1496,12 @@ BeginCopyTo(Relation rel,
errmsg("cannot copy from view \"%s\"",
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.")));
else if (rel->rd_rel->relkind == RELKIND_FOREIGN_TABLE)
ereport(ERROR,
(errcode(ERRCODE_WRONG_OBJECT_TYPE),
@@ -2016,6 +2022,11 @@ CopyFrom(CopyState cstate)
(errcode(ERRCODE_WRONG_OBJECT_TYPE),
errmsg("cannot copy to view \"%s\"",
RelationGetRelationName(cstate->rel))));
+ else if (cstate->rel->rd_rel->relkind == RELKIND_MATVIEW)
+ ereport(ERROR,
+ (errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("cannot copy to materialized view \"%s\"",
+ RelationGetRelationName(cstate->rel))));
else if (cstate->rel->rd_rel->relkind == RELKIND_FOREIGN_TABLE)
ereport(ERROR,
(errcode(ERRCODE_WRONG_OBJECT_TYPE),
View
137 src/backend/commands/createas.c
@@ -2,6 +2,8 @@
*
* createas.c
* Execution of CREATE TABLE ... AS, a/k/a SELECT INTO
+ * Since CREATE MATERIALIZED VIEW shares syntax and most behaviors,
+ * implement that here, too.
*
* We implement this by diverting the query's normal output to a
* specialized DestReceiver type.
@@ -27,8 +29,11 @@
#include "access/xact.h"
#include "catalog/toasting.h"
#include "commands/createas.h"
+#include "commands/matview.h"
#include "commands/prepare.h"
#include "commands/tablecmds.h"
+#include "commands/view.h"
+#include "parser/analyze.h"
#include "parser/parse_clause.h"
#include "rewrite/rewriteHandler.h"
#include "storage/smgr.h"
@@ -43,6 +48,7 @@ typedef struct
{
DestReceiver pub; /* publicly-known function pointers */
IntoClause *into; /* target relation specification */
+ Query *viewParse; /* the query which defines/populates data */
/* These fields are filled by intorel_startup: */
Relation rel; /* relation to write to */
CommandId output_cid; /* cmin to insert in output tuples */
@@ -57,6 +63,62 @@ static void intorel_destroy(DestReceiver *self);
/*
+ * Common setup needed by both normal execution and EXPLAIN ANALYZE.
+ */
+Query *
+SetupForCreateTableAs(Query *query, IntoClause *into, const char *queryString,
+ ParamListInfo params, DestReceiver *dest)
+{
+ List *rewritten;
+ Query *viewParse = NULL;
+
+ Assert(query->commandType == CMD_SELECT);
+
+ if (into->relkind == RELKIND_MATVIEW)
+ viewParse = (Query *) parse_analyze((Node *) copyObject(query),
+ queryString, NULL, 0)->utilityStmt;
+
+ /*
+ * Parse analysis was done already, but we still have to run the rule
+ * rewriter. We do not do AcquireRewriteLocks: we assume the query either
+ * came straight from the parser, or suitable locks were acquired by
+ * plancache.c.
+ *
+ * Because the rewriter and planner tend to scribble on the input, we make
+ * a preliminary copy of the source querytree. This prevents problems in
+ * the case that CTAS is in a portal or plpgsql function and is executed
+ * repeatedly. (See also the same hack in EXPLAIN and PREPARE.)
+ */
+ rewritten = QueryRewrite((Query *) copyObject(query));
+
+ /* SELECT should never rewrite to more or less than one SELECT query */
+ if (list_length(rewritten) != 1)
+ elog(ERROR, "unexpected rewrite result for CREATE TABLE AS SELECT");
+ query = (Query *) linitial(rewritten);
+
+ Assert(query->commandType == CMD_SELECT);
+
+ /* Save the query after rewrite but before planning. */
+ ((DR_intorel *) dest)->viewParse = viewParse;
+ ((DR_intorel *) dest)->into = into;
+
+ if (into->relkind == RELKIND_MATVIEW)
+ {
+ /*
+ * A materialized view would either need to save parameters for use in
+ * maintaining or loading the data or prohibit them entirely. The
+ * latter seems safer and more sane.
+ */
+ if (params != NULL && params->numParams > 0)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("materialized views may not be defined using bound parameters")));
+ }
+
+ return query;
+}
+
+/*
* ExecCreateTableAs -- execute a CREATE TABLE AS command
*/
void
@@ -66,7 +128,6 @@ ExecCreateTableAs(CreateTableAsStmt *stmt, const char *queryString,
Query *query = (Query *) stmt->query;
IntoClause *into = stmt->into;
DestReceiver *dest;
- List *rewritten;
PlannedStmt *plan;
QueryDesc *queryDesc;
ScanDirection dir;
@@ -90,26 +151,8 @@ ExecCreateTableAs(CreateTableAsStmt *stmt, const char *queryString,
return;
}
- Assert(query->commandType == CMD_SELECT);
-
- /*
- * Parse analysis was done already, but we still have to run the rule
- * rewriter. We do not do AcquireRewriteLocks: we assume the query either
- * came straight from the parser, or suitable locks were acquired by
- * plancache.c.
- *
- * Because the rewriter and planner tend to scribble on the input, we make
- * a preliminary copy of the source querytree. This prevents problems in
- * the case that CTAS is in a portal or plpgsql function and is executed
- * repeatedly. (See also the same hack in EXPLAIN and PREPARE.)
- */
- rewritten = QueryRewrite((Query *) copyObject(stmt->query));
- /* SELECT should never rewrite to more or less than one SELECT query */
- if (list_length(rewritten) != 1)
- elog(ERROR, "unexpected rewrite result for CREATE TABLE AS SELECT");
- query = (Query *) linitial(rewritten);
- Assert(query->commandType == CMD_SELECT);
+ query = SetupForCreateTableAs(query, into, queryString, params, dest);
/* plan the query */
plan = pg_plan_query(query, 0, params);
@@ -169,15 +212,21 @@ ExecCreateTableAs(CreateTableAsStmt *stmt, const char *queryString,
int
GetIntoRelEFlags(IntoClause *intoClause)
{
+ int flags;
/*
* We need to tell the executor whether it has to produce OIDs or not,
* because it doesn't have enough information to do so itself (since we
* can't build the target relation until after ExecutorStart).
*/
if (interpretOidsOption(intoClause->options))
- return EXEC_FLAG_WITH_OIDS;
+ flags = EXEC_FLAG_WITH_OIDS;
else
- return EXEC_FLAG_WITHOUT_OIDS;
+ flags = EXEC_FLAG_WITHOUT_OIDS;
+
+ if (intoClause->skipData)
+ flags |= EXEC_FLAG_WITH_NO_DATA;
+
+ return flags;
}
/*
@@ -299,12 +348,38 @@ intorel_startup(DestReceiver *self, int operation, TupleDesc typeinfo)
if (lc != NULL)
ereport(ERROR,
(errcode(ERRCODE_SYNTAX_ERROR),
- errmsg("CREATE TABLE AS specifies too many column names")));
+ errmsg("too many column names are specified")));
+
+ /*
+ * Enforce validations needed for materialized views only.
+ */
+ if (into->relkind == RELKIND_MATVIEW)
+ {
+ /*
+ * Prohibit a data-modifying CTE in the query used to create a
+ * materialized view. It's not sufficiently clear what the user would
+ * want to happen if the MV is refreshed or incrementally maintained.
+ */
+ if (myState->viewParse->hasModifyingCTE)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("materialized views must not use data-modifying statements in WITH")));
+
+ /*
+ * Check whether any temporary database objects are used in the
+ * creation query. It would be hard to refresh data or incrementally
+ * maintain it if a source disappeared.
+ */
+ if (isQueryUsingTempRelation(myState->viewParse))
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("materialized views must not use temporary tables or views")));
+ }
/*
* Actually create the target table
*/
- intoRelationId = DefineRelation(create, RELKIND_RELATION, InvalidOid);
+ intoRelationId = DefineRelation(create, into->relkind, InvalidOid);
/*
* If necessary, create a TOAST table for the target table. Note that
@@ -324,11 +399,22 @@ intorel_startup(DestReceiver *self, int operation, TupleDesc typeinfo)
AlterTableCreateToastTable(intoRelationId, toast_options);
+ /* Create the "view" part of a materialized view. */
+ if (into->relkind == RELKIND_MATVIEW)
+ {
+ StoreViewQuery(intoRelationId, myState->viewParse, false);
+ CommandCounterIncrement();
+ }
+
/*
* Finally we can open the target table
*/
intoRelationDesc = heap_open(intoRelationId, AccessExclusiveLock);
+ if (into->relkind == RELKIND_MATVIEW && !into->skipData)
+ /* Make sure the heap looks good even if no rows are written. */
+ SetRelationIsScannable(intoRelationDesc);
+
/*
* Check INSERT permission on the constructed table.
*
@@ -338,7 +424,8 @@ intorel_startup(DestReceiver *self, int operation, TupleDesc typeinfo)
rte = makeNode(RangeTblEntry);
rte->rtekind = RTE_RELATION;
rte->relid = intoRelationId;
- rte->relkind = RELKIND_RELATION;
+ rte->relkind = into->relkind;
+ rte->isResultRel = true;
rte->requiredPerms = ACL_INSERT;
for (attnum = 1; attnum <= intoRelationDesc->rd_att->natts; attnum++)
View
2  src/backend/commands/event_trigger.c
@@ -67,6 +67,7 @@ static event_trigger_support_data event_trigger_support[] = {
{ "FUNCTION", true },
{ "INDEX", true },
{ "LANGUAGE", true },
+ { "MATERIALIZED VIEW", true },
{ "OPERATOR", true },
{ "OPERATOR CLASS", true },
{ "OPERATOR FAMILY", true },
@@ -217,6 +218,7 @@ check_ddl_tag(const char *tag)
*/
if (pg_strcasecmp(tag, "CREATE TABLE AS") == 0 ||
pg_strcasecmp(tag, "SELECT INTO") == 0 ||
+ pg_strcasecmp(tag, "REFRESH MATERIALIZED VIEW") == 0 ||
pg_strcasecmp(tag, "ALTER DEFAULT PRIVILEGES") == 0 ||
pg_strcasecmp(tag, "ALTER LARGE OBJECT") == 0)
return EVENT_TRIGGER_COMMAND_TAG_OK;
View
35 src/backend/commands/explain.c
@@ -47,7 +47,7 @@ explain_get_index_name_hook_type explain_get_index_name_hook = NULL;
#define X_NOWHITESPACE 4
static void ExplainOneQuery(Query *query, IntoClause *into, ExplainState *es,
- const char *queryString, ParamListInfo params);
+ const char *queryString, DestReceiver *dest, ParamListInfo params);
static void report_triggers(ResultRelInfo *rInfo, bool show_relname,
ExplainState *es);
static double elapsed_time(instr_time *starttime);
@@ -218,7 +218,7 @@ ExplainQuery(ExplainStmt *stmt, const char *queryString,
foreach(l, rewritten)
{
ExplainOneQuery((Query *) lfirst(l), NULL, &es,
- queryString, params);
+ queryString, None_Receiver, params);
/* Separate plans with an appropriate separator */
if (lnext(l) != NULL)
@@ -299,7 +299,8 @@ ExplainResultDesc(ExplainStmt *stmt)
*/
static void
ExplainOneQuery(Query *query, IntoClause *into, ExplainState *es,
- const char *queryString, ParamListInfo params)
+ const char *queryString, DestReceiver *dest,
+ ParamListInfo params)
{
/* planner will not cope with utility statements */
if (query->commandType == CMD_UTILITY)
@@ -319,7 +320,7 @@ ExplainOneQuery(Query *query, IntoClause *into, ExplainState *es,
plan = pg_plan_query(query, 0, params);
/* run it (if needed) and produce output */
- ExplainOnePlan(plan, into, es, queryString, params);
+ ExplainOnePlan(plan, into, es, queryString, dest, params);
}
}
@@ -343,19 +344,23 @@ ExplainOneUtility(Node *utilityStmt, IntoClause *into, ExplainState *es,
if (IsA(utilityStmt, CreateTableAsStmt))
{
+ DestReceiver *dest;
+
/*
* We have to rewrite the contained SELECT and then pass it back to
* ExplainOneQuery. It's probably not really necessary to copy the
* contained parsetree another time, but let's be safe.
*/
CreateTableAsStmt *ctas = (CreateTableAsStmt *) utilityStmt;
- List *rewritten;
+ Query *query = (Query *) ctas->query;
+
+ dest = CreateIntoRelDestReceiver(into);
Assert(IsA(ctas->query, Query));
- rewritten = QueryRewrite((Query *) copyObject(ctas->query));
- Assert(list_length(rewritten) == 1);
- ExplainOneQuery((Query *) linitial(rewritten), ctas->into, es,
- queryString, params);
+
+ query = SetupForCreateTableAs(query, ctas->into, queryString, params, dest);
+
+ ExplainOneQuery(query, ctas->into, es, queryString, dest, params);
}
else if (IsA(utilityStmt, ExecuteStmt))
ExplainExecuteQuery((ExecuteStmt *) utilityStmt, into, es,
@@ -396,9 +401,8 @@ ExplainOneUtility(Node *utilityStmt, IntoClause *into, ExplainState *es,
*/
void
ExplainOnePlan(PlannedStmt *plannedstmt, IntoClause *into, ExplainState *es,
- const char *queryString, ParamListInfo params)
+ const char *queryString, DestReceiver *dest, ParamListInfo params)
{
- DestReceiver *dest;
QueryDesc *queryDesc;
instr_time starttime;
double totaltime = 0;
@@ -422,15 +426,6 @@ ExplainOnePlan(PlannedStmt *plannedstmt, IntoClause *into, ExplainState *es,
PushCopiedSnapshot(GetActiveSnapshot());
UpdateActiveSnapshotCommandId();
- /*
- * Normally we discard the query's output, but if explaining CREATE TABLE
- * AS, we'd better use the appropriate tuple receiver.
- */
- if (into)
- dest = CreateIntoRelDestReceiver(into);
- else
- dest = None_Receiver;
-
/* Create a QueryDesc for the query */
queryDesc = CreateQueryDesc(plannedstmt, queryString,
GetActiveSnapshot(), InvalidSnapshot,
View
6 src/backend/commands/indexcmds.c
@@ -355,7 +355,8 @@ DefineIndex(IndexStmt *stmt,
relationId = RelationGetRelid(rel);
namespaceId = RelationGetNamespace(rel);
- if (rel->rd_rel->relkind != RELKIND_RELATION)
+ if (rel->rd_rel->relkind != RELKIND_RELATION &&
+ rel->rd_rel->relkind != RELKIND_MATVIEW)
{
if (rel->rd_rel->relkind == RELKIND_FOREIGN_TABLE)
@@ -1835,7 +1836,8 @@ ReindexDatabase(const char *databaseName, bool do_system, bool do_user)
{
Form_pg_class classtuple = (Form_pg_class) GETSTRUCT(tuple);
- if (classtuple->relkind != RELKIND_RELATION)
+ if (classtuple->relkind != RELKIND_RELATION &&
+ classtuple->relkind != RELKIND_MATVIEW)
continue;
/* Skip temp tables of other backends; we can't reindex them at all */
View
374 src/backend/commands/matview.c
@@ -0,0 +1,374 @@
+/*-------------------------------------------------------------------------
+ *
+ * matview.c
+ * materialized view support
+ *
+ * Portions Copyright (c) 1996-2012, PostgreSQL Global Development Group
+ * Portions Copyright (c) 1994, Regents of the University of California
+ *
+ *
+ * IDENTIFICATION
+ * src/backend/commands/matview.c
+ *
+ *-------------------------------------------------------------------------
+ */
+#include "postgres.h"
+
+#include "access/multixact.h"
+#include "access/relscan.h"
+#include "access/xact.h"
+#include "catalog/catalog.h"
+#include "catalog/heap.h"
+#include "catalog/namespace.h"
+#include "commands/cluster.h"
+#include "commands/matview.h"
+#include "commands/tablecmds.h"
+#include "executor/executor.h"
+#include "miscadmin.h"
+#include "rewrite/rewriteHandler.h"
+#include "storage/lmgr.h"
+#include "storage/smgr.h"
+#include "tcop/tcopprot.h"
+#include "utils/snapmgr.h"
+
+
+typedef struct
+{
+ DestReceiver pub; /* publicly-known function pointers */
+ Oid transientoid; /* OID of new heap into which to store */
+ /* These fields are filled by transientrel_startup: */
+ Relation transientrel; /* relation to write to */
+ CommandId output_cid; /* cmin to insert in output tuples */
+ int hi_options; /* heap_insert performance options */
+ BulkInsertState bistate; /* bulk insert state */
+} DR_transientrel;
+
+static void transientrel_startup(DestReceiver *self, int operation, TupleDesc typeinfo);
+static void transientrel_receive(TupleTableSlot *slot, DestReceiver *self);
+static void transientrel_shutdown(DestReceiver *self);
+static void transientrel_destroy(DestReceiver *self);
+static void refresh_matview_datafill(DestReceiver *dest, Query *query,
+ const char *queryString);
+
+/*
+ * SetRelationIsScannable
+ * Make the relation appear scannable.
+ *
+ * NOTE: This is only implemented for materialized views. The heap starts out
+ * in a state that doesn't look scannable, and can only transition from there
+ * to scannable, unless a new heap is created.
+ *
+ * NOTE: caller must be holding an appropriate lock on the relation.
+ */
+void
+SetRelationIsScannable(Relation relation)
+{
+ Page page;
+
+ Assert(relation->rd_rel->relkind == RELKIND_MATVIEW);
+ Assert(relation->rd_isscannable == false);
+
+ RelationOpenSmgr(relation);
+ page = (Page) palloc(BLCKSZ);
+ PageInit(page, BLCKSZ, 0);
+ smgrextend(relation->rd_smgr, MAIN_FORKNUM, 0, (char *) page, true);
+ pfree(page);
+
+ smgrimmedsync(relation->rd_smgr, MAIN_FORKNUM);
+
+ RelationCacheInvalidateEntry(relation->rd_id);
+}
+
+/*
+ * ExecRefreshMatView -- execute a REFRESH MATERIALIZED VIEW command
+ *
+ * This refreshes the materialized view by creating a new table and swapping
+ * the relfilenodes of the new table and the old materialized view, so the OID
+ * of the original materialized view is preserved. Thus we do not lose GRANT
+ * nor references to this materialized view.
+ *
+ * If WITH NO DATA was specified, this is effectively like a TRUNCATE;
+ * otherwise it is like a TRUNCATE followed by an INSERT using the SELECT
+ * statement associated with the materialized view. The statement node's
+ * skipData field is used to indicate that the clause was used.
+ *
+ * Indexes are rebuilt too, via REINDEX. Since we are effectively bulk-loading
+ * the new heap, it's better to create the indexes afterwards than to fill them
+ * incrementally while we load.
+ *
+ * The scannable state is changed based on whether the contents reflect the
+ * result set of the materialized view's query.
+ */
+void
+ExecRefreshMatView(RefreshMatViewStmt *stmt, const char *queryString,
+ ParamListInfo params, char *completionTag)
+{
+ Oid matviewOid;
+ Relation matviewRel;
+ RewriteRule *rule;
+ List *actions;
+ Query *dataQuery;
+ Oid tableSpace;
+ Oid OIDNewHeap;
+ DestReceiver *dest;
+
+ /*
+ * Get a lock until end of transaction.
+ */
+ matviewOid = RangeVarGetRelidExtended(stmt->relation,
+ AccessExclusiveLock, false, false,
+ RangeVarCallbackOwnsTable, NULL);
+ matviewRel = heap_open(matviewOid, NoLock);
+
+ /* Make sure it is a materialized view. */
+ if (matviewRel->rd_rel->relkind != RELKIND_MATVIEW)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("\"%s\" is not a materialized view",
+ RelationGetRelationName(matviewRel))));
+
+ /*
+ * We're not using materialized views in the system catalogs.
+ */
+ Assert(!IsSystemRelation(matviewRel));
+
+ Assert(!matviewRel->rd_rel->relhasoids);
+
+ /*
+ * Check that everything is correct for a refresh. Problems at this point
+ * are internal errors, so elog is sufficient.
+ */
+ if (matviewRel->rd_rel->relhasrules == false ||
+ matviewRel->rd_rules->numLocks < 1)