@@ -39,6 +39,10 @@ ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
3939 DETACH PARTITION <replaceable class="parameter">partition_name</replaceable> [ CONCURRENTLY | FINALIZE ]
4040ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
4141 MERGE PARTITIONS (<replaceable class="parameter">partition_name1</replaceable>, <replaceable class="parameter">partition_name2</replaceable> [, ...]) INTO <replaceable class="parameter">partition_name</replaceable>
42+ ALTER TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
43+ SPLIT PARTITION <replaceable class="parameter">partition_name</replaceable> INTO
44+ (PARTITION <replaceable class="parameter">partition_name1</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT },
45+ PARTITION <replaceable class="parameter">partition_name2</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT } [, ...])
4246
4347<phrase>where <replaceable class="parameter">action</replaceable> is one of:</phrase>
4448
@@ -1256,14 +1260,100 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
12561260 </listitem>
12571261 </varlistentry>
12581262
1263+ <varlistentry id="sql-altertable-split-partition">
1264+ <term>
1265+ <literal>SPLIT PARTITION <replaceable class="parameter">partition_name</replaceable> INTO (
1266+ PARTITION <replaceable class="parameter">partition_name1</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT },
1267+ PARTITION <replaceable class="parameter">partition_name2</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }
1268+ [, ...])</literal>
1269+ </term>
1270+
1271+ <listitem>
1272+ <para>
1273+ This form splits a single partition of the target table into new
1274+ partitions. Hash-partitioned target table is not supported.
1275+ Only a simple, non-partitioned partition can be split.
1276+ If the split partition is the <literal>DEFAULT</literal> partition, one of
1277+ the new partitions must be <literal>DEFAULT</literal>.
1278+ If the partitioned table does not have <literal>DEFAULT</literal> partition,
1279+ <literal>DEFAULT</literal> partition can be defined as one of the new partitions.
1280+ </para>
1281+
1282+ <para>
1283+ Bounds of new partitions should not overlap with new and existing partitions
1284+ (except <replaceable class="parameter">partition_name</replaceable>).
1285+ The combined bounds of new partitions <literal>
1286+ <replaceable class="parameter">partition_name1</replaceable>,
1287+ <replaceable class="parameter">partition_name2</replaceable>[, ...]
1288+ </literal> should be equal to the bound of the split partition
1289+ <replaceable class="parameter">partition_name</replaceable>.
1290+ One of the new partitions can have the same name as the split partition <replaceable class="parameter">partition_name</replaceable>
1291+ (this is suitable in case of splitting the <literal>DEFAULT</literal>
1292+ partition: after the split, the <literal>DEFAULT</literal> partition remains with the same
1293+ name, but its partition bound changes).
1294+ </para>
1295+
1296+ <para>
1297+ New partitions will have the same owner as the parent partition.
1298+ It is the user's responsibility to setup <acronym>ACL</acronym> on new
1299+ partitions.
1300+ </para>
1301+
1302+ <para>
1303+ <command>ALTER TABLE SPLIT PARTITION</command> uses the partitioned table itself
1304+ as the template to construct new partitions.
1305+ New partitions will inherit the same table access method, persistence
1306+ type, and tablespace as the partitioned table.
1307+ </para>
1308+
1309+ <para>
1310+ Constraints, column defaults, column generation expressions, identity columns,
1311+ indexes, triggers are copied from the partitioned table to the new
1312+ partitions. But extended statistics, security policies etc won't copied from
1313+ the partitioned table.
1314+ Indexes and identity columns copied from the partitioned table will be
1315+ created afterward, once the data has been moved into the new partitions.
1316+ </para>
1317+
1318+ <para>
1319+ When a partition is split, any objects depend on this partition, such as
1320+ constraints, triggers, extended statistics etc will be dropped. This occurs
1321+ because <command>ALTER TABLE SPLIT PARTITION</command> uses the partitioned
1322+ table itself as the template to reconstruct these objects later.
1323+ Eventually we will drop the split partition (using <literal>RESTRICT</literal> mode) too,
1324+ therefore if any objects still dependent on it,
1325+ <command>ALTER TABLE SPLIT PARTITION</command> would fail.
1326+ (see <xref linkend="ddl-depend"/>).
1327+ </para>
1328+
1329+ <note>
1330+ <para>
1331+ Split partition acquires an <literal>ACCESS EXCLUSIVE</literal> lock on
1332+ the parent table, in addition to the <literal>ACCESS EXCLUSIVE</literal>
1333+ lock on the table being split.
1334+ </para>
1335+ </note>
1336+ <note>
1337+
1338+ <para>
1339+ <command>ALTER TABLE SPLIT PARTITION</command> creates new partitions and
1340+ moves data from the split partition into them, which can take a long
1341+ time. So it is not recommended to use the command for splitting a
1342+ small fraction of rows out of a very big partition.
1343+ </para>
1344+ </note>
1345+ </listitem>
1346+ </varlistentry>
1347+
12591348 </variablelist>
12601349 </para>
12611350
12621351 <para>
12631352 All the forms of <command>ALTER TABLE</command> that act on a single table,
12641353 except <literal>RENAME</literal>, <literal>SET SCHEMA</literal>,
12651354 <literal>ATTACH PARTITION</literal>, <literal>DETACH PARTITION</literal>,
1266- and <literal>MERGE PARTITIONS</literal>, can be combined into
1355+ <literal>MERGE PARTITIONS</literal>, and <literal>SPLIT PARTITION</literal>
1356+ can be combined into
12671357 a list of multiple alterations to be applied together. For example, it
12681358 is possible to add several columns and/or alter the type of several
12691359 columns in a single command. This is particularly useful with large
@@ -1507,7 +1597,7 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
15071597 <listitem>
15081598 <para>
15091599 The name of the table to attach as a new partition or to detach from this table,
1510- or the name of the new merged partition.
1600+ or the name of split partition, or the name of the new merged partition.
15111601 </para>
15121602 </listitem>
15131603 </varlistentry>
@@ -1517,7 +1607,8 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
15171607 <term><replaceable class="parameter">partition_name2</replaceable></term>
15181608 <listitem>
15191609 <para>
1520- The names of the tables being merged into the new partition.
1610+ The names of the tables being merged into the new partition or split into
1611+ new partitions.
15211612 </para>
15221613 </listitem>
15231614 </varlistentry>
@@ -1950,6 +2041,24 @@ ALTER TABLE measurement
19502041 DETACH PARTITION measurement_y2015m12;
19512042</programlisting></para>
19522043
2044+ <para>
2045+ To split a single partition of the range-partitioned table:
2046+ <programlisting>
2047+ ALTER TABLE sales_range SPLIT PARTITION sales_feb_mar_apr2023 INTO
2048+ (PARTITION sales_feb2023 FOR VALUES FROM ('2023-02-01') TO ('2023-03-01'),
2049+ PARTITION sales_mar2023 FOR VALUES FROM ('2023-03-01') TO ('2023-04-01'),
2050+ PARTITION sales_apr2023 FOR VALUES FROM ('2023-04-01') TO ('2023-05-01'));
2051+ </programlisting></para>
2052+
2053+ <para>
2054+ To split a single partition of the list-partitioned table:
2055+ <programlisting>
2056+ ALTER TABLE sales_list SPLIT PARTITION sales_all INTO
2057+ (PARTITION sales_west FOR VALUES IN ('Lisbon', 'New York', 'Madrid'),
2058+ PARTITION sales_east FOR VALUES IN ('Bejing', 'Delhi', 'Vladivostok'),
2059+ PARTITION sales_central FOR VALUES IN ('Warsaw', 'Berlin', 'Kyiv'));
2060+ </programlisting></para>
2061+
19532062 <para>
19542063 To merge several partitions into one partition of the target table:
19552064<programlisting>
0 commit comments