Permalink
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...
1 parent b15a6da commit 3bf3ab8c563699138be02f9dc305b7b77a724307 @kgrittn kgrittn committed Mar 4, 2013
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
@@ -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"
@@ -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 "
@@ -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);
@@ -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 " \
@@ -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);
@@ -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)
@@ -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
@@ -13743,6 +13743,10 @@ SELECT pg_type_is_visible('myschema.widget'::regtype);
<primary>pg_tablespace_location</primary>
</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>
@@ -13906,6 +13910,11 @@ SELECT pg_type_is_visible('myschema.widget'::regtype);
<entry><type>text</type></entry>
<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>
@@ -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">
@@ -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> |
@@ -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>
@@ -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';
@@ -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>
Oops, something went wrong.

0 comments on commit 3bf3ab8

Please sign in to comment.