From eff0406d5ca8132e8a199ced72b8a0cc3b84ea22 Mon Sep 17 00:00:00 2001
From: Michael Harris <harmic@gmail.com>
Date: Fri, 20 Sep 2024 11:17:07 +1000
Subject: [PATCH v6] Implementation of the 'ONLY' feature for ANALYZE and
 VACUUM.

This patch also changes the behaivour of ANALYZE and
VACUUM when given on parent tables in an inheritance
structure, to align with the case of partitioned tables.
In the absence of ONLY, descendant tables will be
included.

Refer to the thread at:
  https://www.postgresql.org/message-id/flat/CADofcAWATx_haD%3DQkSxHbnTsAe6%2Be0Aw8Eh4H8cXyogGvn_kOg%40mail.gmail.com
---
 doc/src/sgml/ddl.sgml                | 22 ++++----
 doc/src/sgml/monitoring.sgml         |  6 +--
 doc/src/sgml/ref/analyze.sgml        | 36 +++++++------
 doc/src/sgml/ref/vacuum.sgml         | 10 ++--
 src/backend/commands/vacuum.c        | 39 ++++++++++----
 src/backend/parser/gram.y            |  2 +-
 src/test/regress/expected/vacuum.out | 80 ++++++++++++++++++++++++++++
 src/test/regress/sql/vacuum.sql      | 52 ++++++++++++++++++
 8 files changed, 203 insertions(+), 44 deletions(-)

diff --git a/doc/src/sgml/ddl.sgml b/doc/src/sgml/ddl.sgml
index b671858627..c7de29ae71 100644
--- a/doc/src/sgml/ddl.sgml
+++ b/doc/src/sgml/ddl.sgml
@@ -3778,12 +3778,14 @@ VALUES ('Albany', NULL, NULL, 'NY');
    not <literal>INSERT</literal> or <literal>ALTER TABLE ...
    RENAME</literal>) typically default to including child tables and
    support the <literal>ONLY</literal> notation to exclude them.
-   Commands that do database maintenance and tuning
-   (e.g., <literal>REINDEX</literal>, <literal>VACUUM</literal>)
-   typically only work on individual, physical tables and do not
-   support recursing over inheritance hierarchies.  The respective
-   behavior of each individual command is documented in its reference
-   page (<xref linkend="sql-commands"/>).
+   Some commands that do database maintenance and tuning
+   (e.g., <literal>REINDEX</literal>) only work on individual, physical
+   tables and do not support recursing over inheritance hierarchies,
+   while other maintenance commands (e.g., <literal>VACUUM</literal>,
+   <literal>ANALYZE</literal>) default to including child tables
+   and support the <literal>ONLY</literal> notation to exclude them.
+   The respective behavior of each individual command is documented
+   in its reference page (<xref linkend="sql-commands"/>).
   </para>
 
   <para>
@@ -4854,11 +4856,11 @@ ALTER TABLE measurement_y2008m02 INHERIT measurement;
 
       <listitem>
        <para>
-        If you are using manual <command>VACUUM</command> or
-        <command>ANALYZE</command> commands, don't forget that
-        you need to run them on each child table individually. A command like:
+        Manual <command>VACUUM</command> or <command>ANALYZE</command> commands
+        will automatically process all descendant tables. If this is undesirable,
+        you can use the <literal>ONLY</literal> keyword. A command like:
 <programlisting>
-ANALYZE measurement;
+ANALYZE ONLY measurement;
 </programlisting>
         will only process the root table.
        </para>
diff --git a/doc/src/sgml/monitoring.sgml b/doc/src/sgml/monitoring.sgml
index a2fda4677d..82d6aef858 100644
--- a/doc/src/sgml/monitoring.sgml
+++ b/doc/src/sgml/monitoring.sgml
@@ -5525,9 +5525,9 @@ FROM pg_stat_get_backend_idset() AS backendid;
 
   <note>
    <para>
-    Note that when <command>ANALYZE</command> is run on a partitioned table,
-    all of its partitions are also recursively analyzed.
-    In that case, <command>ANALYZE</command>
+    Note that when <command>ANALYZE</command> is run on a partitioned table
+    without the <literal>ONLY</literal> keyword, all of its partitions are
+    also recursively analyzed. In that case, <command>ANALYZE</command>
     progress is reported first for the parent table, whereby its inheritance
     statistics are collected, followed by that for each partition.
    </para>
diff --git a/doc/src/sgml/ref/analyze.sgml b/doc/src/sgml/ref/analyze.sgml
index 2b94b378e9..92e465ca59 100644
--- a/doc/src/sgml/ref/analyze.sgml
+++ b/doc/src/sgml/ref/analyze.sgml
@@ -31,7 +31,7 @@ ANALYZE [ ( <replaceable class="parameter">option</replaceable> [, ...] ) ] [ <r
 
 <phrase>and <replaceable class="parameter">table_and_columns</replaceable> is:</phrase>
 
-    <replaceable class="parameter">table_name</replaceable> [ ( <replaceable class="parameter">column_name</replaceable> [, ...] ) ]
+    [ ONLY ] <replaceable class="parameter">table_name</replaceable> [ * ] [ ( <replaceable class="parameter">column_name</replaceable> [, ...] ) ]
 </synopsis>
  </refsynopsisdiv>
 
@@ -142,9 +142,12 @@ ANALYZE [ ( <replaceable class="parameter">option</replaceable> [, ...] ) ] [ <r
       The name (possibly schema-qualified) of a specific table to
       analyze.  If omitted, all regular tables, partitioned tables, and
       materialized views in the current database are analyzed (but not
-      foreign tables).  If the specified table is a partitioned table, both the
-      inheritance statistics of the partitioned table as a whole and
-      statistics of the individual partitions are updated.
+      foreign tables). If <literal>ONLY</literal> is specified before
+      the table name, only that table is analyzed. If <literal>ONLY</literal>
+      is not specified, the table and all its descendant tables or partitions
+      (if any) are analyzed.  Optionally, <literal>*</literal>
+      can be specified after the table name to explicitly indicate that
+      descendant tables are included.
      </para>
     </listitem>
    </varlistentry>
@@ -284,22 +287,23 @@ ANALYZE [ ( <replaceable class="parameter">option</replaceable> [, ...] ) ] [ <r
     <command>ANALYZE</command> gathers two sets of statistics: one on the rows
     of the parent table only, and a second including rows of both the parent
     table and all of its children.  This second set of statistics is needed when
-    planning queries that process the inheritance tree as a whole.  The child
-    tables themselves are not individually analyzed in this case.
-    The autovacuum daemon, however, will only consider inserts or
-    updates on the parent table itself when deciding whether to trigger an
-    automatic analyze for that table.  If that table is rarely inserted into
-    or updated, the inheritance statistics will not be up to date unless you
-    run <command>ANALYZE</command> manually.
+    planning queries that process the inheritance tree as a whole.  If the
+    <literal>ONLY</literal> keyword is used, child tables themselves are not
+    individually analyzed. The autovacuum daemon, however, will only consider
+    inserts or updates on the parent table itself when deciding whether to
+    trigger an automatic analyze for that table.  If that table is rarely
+    inserted into or updated, the inheritance statistics will not be up to
+    date unless you run <command>ANALYZE</command> manually.
   </para>
 
   <para>
     For partitioned tables, <command>ANALYZE</command> gathers statistics by
-    sampling rows from all partitions; in addition, it will recurse into each
-    partition and update its statistics.  Each leaf partition is analyzed only
-    once, even with multi-level partitioning.  No statistics are collected for
-    only the parent table (without data from its partitions), because with
-    partitioning it's guaranteed to be empty.
+    sampling rows from all partitions. If <literal>ONLY</literal> is not
+    specified, it will also recurse into each partition and update its
+    statistics.  Each leaf partition is analyzed only once, even with
+    multi-level partitioning.  No statistics are collected for only the
+    parent table (without data from its partitions), because with
+    partitioning it is guaranteed to be empty.
   </para>
 
   <para>
diff --git a/doc/src/sgml/ref/vacuum.sgml b/doc/src/sgml/ref/vacuum.sgml
index 9857b35627..465f9fecf7 100644
--- a/doc/src/sgml/ref/vacuum.sgml
+++ b/doc/src/sgml/ref/vacuum.sgml
@@ -42,7 +42,7 @@ VACUUM [ ( <replaceable class="parameter">option</replaceable> [, ...] ) ] [ <re
 
 <phrase>and <replaceable class="parameter">table_and_columns</replaceable> is:</phrase>
 
-    <replaceable class="parameter">table_name</replaceable> [ ( <replaceable class="parameter">column_name</replaceable> [, ...] ) ]
+    [ ONLY ] <replaceable class="parameter">table_name</replaceable> [ * ] [ ( <replaceable class="parameter">column_name</replaceable> [, ...] ) ]
 </synopsis>
  </refsynopsisdiv>
 
@@ -401,8 +401,12 @@ VACUUM [ ( <replaceable class="parameter">option</replaceable> [, ...] ) ] [ <re
     <listitem>
      <para>
       The name (optionally schema-qualified) of a specific table or
-      materialized view to vacuum.  If the specified table is a partitioned
-      table, all of its leaf partitions are vacuumed.
+      materialized view to vacuum.  If <literal>ONLY</literal> is specified before
+      the table name, only that table is vacuumed. If <literal>ONLY</literal>
+      is not specified, the table and all its descendant tables or partitions
+      (if any) are also vacuumed.  Optionally, <literal>*</literal>
+      can be specified after the table name to explicitly indicate that
+      descendant tables are included.
      </para>
     </listitem>
    </varlistentry>
diff --git a/src/backend/commands/vacuum.c b/src/backend/commands/vacuum.c
index 7d8e9d2045..951e00acee 100644
--- a/src/backend/commands/vacuum.c
+++ b/src/backend/commands/vacuum.c
@@ -851,7 +851,8 @@ vacuum_open_relation(Oid relid, RangeVar *relation, bits32 options,
 
 /*
  * Given a VacuumRelation, fill in the table OID if it wasn't specified,
- * and optionally add VacuumRelations for partitions of the table.
+ * and optionally add VacuumRelations for partitions or descendant tables
+ * of the table.
  *
  * If a VacuumRelation does not have an OID supplied and is a partitioned
  * table, an extra entry will be added to the output for each partition.
@@ -879,11 +880,15 @@ expand_vacuum_rel(VacuumRelation *vrel, MemoryContext vac_context,
 	}
 	else
 	{
-		/* Process a specific relation, and possibly partitions thereof */
+		/*
+		 * Process a specific relation, and possibly partitions and/or child
+		 * tables thereof
+		 */
 		Oid			relid;
 		HeapTuple	tuple;
 		Form_pg_class classForm;
-		bool		include_parts;
+		bool		include_children;
+		bool		is_partitioned_table;
 		int			rvr_opts;
 
 		/*
@@ -944,20 +949,32 @@ expand_vacuum_rel(VacuumRelation *vrel, MemoryContext vac_context,
 			MemoryContextSwitchTo(oldcontext);
 		}
 
+		/*
+		 * Vacuuming a partitioned table with ONLY will not do anything since
+		 * the partitioned table itself is empty. Issue a warning if the user
+		 * requests this.
+		 */
+		include_children = vrel->relation->inh;
+		is_partitioned_table = (classForm->relkind == RELKIND_PARTITIONED_TABLE);
+		if ((options & VACOPT_VACUUM) && is_partitioned_table && !include_children)
+			ereport(WARNING,
+					(errmsg("VACUUM ONLY of partitioned table \"%s\" has no effect",
+							vrel->relation->relname)));
+
 
-		include_parts = (classForm->relkind == RELKIND_PARTITIONED_TABLE);
 		ReleaseSysCache(tuple);
 
 		/*
-		 * If it is, make relation list entries for its partitions.  Note that
-		 * the list returned by find_all_inheritors() includes the passed-in
-		 * OID, so we have to skip that.  There's no point in taking locks on
-		 * the individual partitions yet, and doing so would just add
+		 * Unless the user has specified ONLY, make relation list entries for
+		 * its partitions and/or descendant tables.  Note that the list
+		 * returned by find_all_inheritors() includes the passed-in OID, so we
+		 * have to skip that.  There's no point in taking locks on the
+		 * individual partitions/tables yet, and doing so would just add
 		 * unnecessary deadlock risk.  For this last reason we do not check
-		 * yet the ownership of the partitions, which get added to the list to
-		 * process.  Ownership will be checked later on anyway.
+		 * yet the ownership of the partitions/tables, which get added to the
+		 * list to process.  Ownership will be checked later on anyway.
 		 */
-		if (include_parts)
+		if (include_children)
 		{
 			List	   *part_oids = find_all_inheritors(relid, NoLock, NULL);
 			ListCell   *part_lc;
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index ab304ca989..b1d4642c59 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -11921,7 +11921,7 @@ opt_name_list:
 		;
 
 vacuum_relation:
-			qualified_name opt_name_list
+			relation_expr opt_name_list
 				{
 					$$ = (Node *) makeVacuumRelation($1, InvalidOid, $2);
 				}
diff --git a/src/test/regress/expected/vacuum.out b/src/test/regress/expected/vacuum.out
index 2eba712887..7165235ece 100644
--- a/src/test/regress/expected/vacuum.out
+++ b/src/test/regress/expected/vacuum.out
@@ -291,6 +291,86 @@ ANALYZE vactst, vactst;
 BEGIN;  -- ANALYZE behaves differently inside a transaction block
 ANALYZE vactst, vactst;
 COMMIT;
+-- ANALYZE ONLY / VACUUM ONLY on partitioned table
+CREATE TABLE only_parted (a int, b char) PARTITION BY LIST (a);
+CREATE TABLE only_parted1 PARTITION OF only_parted FOR VALUES IN (1);
+INSERT INTO only_parted VALUES (1, 'a');
+-- Only partitioned table is analyzed
+ANALYZE ONLY only_parted;
+SELECT relname, last_analyze is not null as analyzed, last_vacuum is not null as vacuumed FROM pg_stat_user_tables
+  WHERE relname like 'only_parted%'
+  ORDER BY relname;
+   relname    | analyzed | vacuumed 
+--------------+----------+----------
+ only_parted  | t        | f
+ only_parted1 | f        | f
+(2 rows)
+
+-- Partitioned table and partitions are analyzed
+ANALYZE only_parted;
+SELECT relname, last_analyze is not null as analyzed, last_vacuum is not null as vacuumed FROM pg_stat_user_tables
+  WHERE relname like 'only_parted%'
+  ORDER BY relname;
+   relname    | analyzed | vacuumed 
+--------------+----------+----------
+ only_parted  | t        | f
+ only_parted1 | t        | f
+(2 rows)
+
+VACUUM ONLY vacparted; -- gives warning
+WARNING:  VACUUM ONLY of partitioned table "vacparted" has no effect
+ANALYZE ONLY vacparted(a,b); -- combine ONLY with column list
+-- ANALYZE ONLY on inherited tables
+CREATE TABLE only_inh_parent (a int primary key, b TEXT);
+CREATE TABLE only_inh_child () INHERITS (only_inh_parent);
+INSERT INTO only_inh_child(a,b) VALUES (1, 'aaa'), (2, 'bbb'), (3, 'ccc');
+-- Only parent is ANALYZED
+ANALYZE ONLY only_inh_parent;
+SELECT relname, last_analyze is not null as analyzed, last_vacuum is not null as vacuumed FROM pg_stat_user_tables
+  WHERE relname like 'only_inh%'
+  ORDER BY relname;
+     relname     | analyzed | vacuumed 
+-----------------+----------+----------
+ only_inh_child  | f        | f
+ only_inh_parent | t        | f
+(2 rows)
+
+-- Parent and child are ANALYZED
+ANALYZE only_inh_parent;
+SELECT relname, last_analyze is not null as analyzed, last_vacuum is not null as vacuumed FROM pg_stat_user_tables
+  WHERE relname like 'only_inh%'
+  ORDER BY relname;
+     relname     | analyzed | vacuumed 
+-----------------+----------+----------
+ only_inh_child  | t        | f
+ only_inh_parent | t        | f
+(2 rows)
+
+-- Only parent is VACUUMED
+VACUUM ONLY only_inh_parent;
+SELECT relname, last_analyze is not null as analyzed, last_vacuum is not null as vacuumed FROM pg_stat_user_tables
+  WHERE relname like 'only_inh%'
+  ORDER BY relname;
+     relname     | analyzed | vacuumed 
+-----------------+----------+----------
+ only_inh_child  | t        | f
+ only_inh_parent | t        | t
+(2 rows)
+
+-- Parent and child are VACUUMED
+VACUUM only_inh_parent;
+SELECT relname, last_analyze is not null as analyzed, last_vacuum is not null as vacuumed FROM pg_stat_user_tables
+  WHERE relname like 'only_inh%'
+  ORDER BY relname;
+     relname     | analyzed | vacuumed 
+-----------------+----------+----------
+ only_inh_child  | t        | t
+ only_inh_parent | t        | t
+(2 rows)
+
+DROP TABLE only_parted CASCADE;
+DROP TABLE only_inh_parent CASCADE;
+NOTICE:  drop cascades to table only_inh_child
 -- parenthesized syntax for ANALYZE
 ANALYZE (VERBOSE) does_not_exist;
 ERROR:  relation "does_not_exist" does not exist
diff --git a/src/test/regress/sql/vacuum.sql b/src/test/regress/sql/vacuum.sql
index 548cd7acca..fc84df0f07 100644
--- a/src/test/regress/sql/vacuum.sql
+++ b/src/test/regress/sql/vacuum.sql
@@ -233,6 +233,58 @@ BEGIN;  -- ANALYZE behaves differently inside a transaction block
 ANALYZE vactst, vactst;
 COMMIT;
 
+-- ANALYZE ONLY / VACUUM ONLY on partitioned table
+CREATE TABLE only_parted (a int, b char) PARTITION BY LIST (a);
+CREATE TABLE only_parted1 PARTITION OF only_parted FOR VALUES IN (1);
+INSERT INTO only_parted VALUES (1, 'a');
+
+-- Only partitioned table is analyzed
+ANALYZE ONLY only_parted;
+SELECT relname, last_analyze is not null as analyzed, last_vacuum is not null as vacuumed FROM pg_stat_user_tables
+  WHERE relname like 'only_parted%'
+  ORDER BY relname;
+
+-- Partitioned table and partitions are analyzed
+ANALYZE only_parted;
+SELECT relname, last_analyze is not null as analyzed, last_vacuum is not null as vacuumed FROM pg_stat_user_tables
+  WHERE relname like 'only_parted%'
+  ORDER BY relname;
+
+VACUUM ONLY vacparted; -- gives warning
+ANALYZE ONLY vacparted(a,b); -- combine ONLY with column list
+
+-- ANALYZE ONLY on inherited tables
+CREATE TABLE only_inh_parent (a int primary key, b TEXT);
+CREATE TABLE only_inh_child () INHERITS (only_inh_parent);
+INSERT INTO only_inh_child(a,b) VALUES (1, 'aaa'), (2, 'bbb'), (3, 'ccc');
+
+-- Only parent is ANALYZED
+ANALYZE ONLY only_inh_parent;
+SELECT relname, last_analyze is not null as analyzed, last_vacuum is not null as vacuumed FROM pg_stat_user_tables
+  WHERE relname like 'only_inh%'
+  ORDER BY relname;
+
+-- Parent and child are ANALYZED
+ANALYZE only_inh_parent;
+SELECT relname, last_analyze is not null as analyzed, last_vacuum is not null as vacuumed FROM pg_stat_user_tables
+  WHERE relname like 'only_inh%'
+  ORDER BY relname;
+
+-- Only parent is VACUUMED
+VACUUM ONLY only_inh_parent;
+SELECT relname, last_analyze is not null as analyzed, last_vacuum is not null as vacuumed FROM pg_stat_user_tables
+  WHERE relname like 'only_inh%'
+  ORDER BY relname;
+
+-- Parent and child are VACUUMED
+VACUUM only_inh_parent;
+SELECT relname, last_analyze is not null as analyzed, last_vacuum is not null as vacuumed FROM pg_stat_user_tables
+  WHERE relname like 'only_inh%'
+  ORDER BY relname;
+
+DROP TABLE only_parted CASCADE;
+DROP TABLE only_inh_parent CASCADE;
+
 -- parenthesized syntax for ANALYZE
 ANALYZE (VERBOSE) does_not_exist;
 ANALYZE (nonexistent-arg) does_not_exist;
-- 
2.31.1

