DDL command handling matrix v5.6
The following table describes the utility or DDL commands that are allowed, the ones that are replicated, and the type of global lock they take when they're replicated.
For some more complex statements like ALTER TABLE
, these can differ depending
on the subcommands executed. Every such command has detailed explanation
under the following table.
Command matrix
Command | Allowed | Replicated | Lock |
---|---|---|---|
ALTER AGGREGATE | Y | Y | DDL |
ALTER CAST | Y | Y | DDL |
ALTER COLLATION | Y | Y | DDL |
ALTER CONVERSION | Y | Y | DDL |
ALTER DATABASE | Y | N | N |
ALTER DATABASE LINK | Y | Y | DDL |
ALTER DEFAULT PRIVILEGES | Y | Y | DDL |
ALTER DIRECTORY | Y | Y | DDL |
ALTER DOMAIN | Y | Y | DDL |
ALTER EVENT TRIGGER | Y | Y | DDL |
ALTER EXTENSION | Y | Y | DDL |
ALTER FOREIGN DATA WRAPPER | Y | Y | DDL |
ALTER FOREIGN TABLE | Y | Y | DDL |
ALTER FUNCTION | Y | Y | DDL |
ALTER INDEX | Y | Y | DDL |
ALTER LANGUAGE | Y | Y | DDL |
ALTER LARGE OBJECT | N | N | N |
ALTER MATERIALIZED VIEW | Y | N | N |
ALTER OPERATOR | Y | Y | DDL |
ALTER OPERATOR CLASS | Y | Y | DDL |
ALTER OPERATOR FAMILY | Y | Y | DDL |
ALTER PACKAGE | Y | Y | DDL |
ALTER POLICY | Y | Y | DDL |
ALTER PROCEDURE | Y | Y | DDL |
ALTER PROFILE | Y | Y | Details |
ALTER PUBLICATION | Y | Y | DDL |
ALTER QUEUE | Y | Y | DDL |
ALTER QUEUE TABLE | Y | Y | DDL |
ALTER REDACTION POLICY | Y | Y | DDL |
ALTER RESOURCE GROUP | Y | N | N |
ALTER ROLE | Y | Y | DDL |
ALTER ROUTINE | Y | Y | DDL |
ALTER RULE | Y | Y | DDL |
ALTER SCHEMA | Y | Y | DDL |
ALTER SEQUENCE | Details | Y | DML |
ALTER SERVER | Y | Y | DDL |
ALTER SESSION | Y | N | N |
ALTER STATISTICS | Y | Y | DDL |
ALTER SUBSCRIPTION | Y | Y | DDL |
ALTER SYNONYM | Y | Y | DDL |
ALTER SYSTEM | Y | N | N |
ALTER TABLE | Details | Y | Details |
ALTER TABLESPACE | Y | N | N |
ALTER TEXT SEARCH CONFIGURATION | Y | Y | DDL |
ALTER TEXT SEARCH DICTIONARY | Y | Y | DDL |
ALTER TEXT SEARCH PARSER | Y | Y | DDL |
ALTER TEXT SEARCH TEMPLATE | Y | Y | DDL |
ALTER TRIGGER | Y | Y | DDL |
ALTER TYPE | Y | Y | DDL |
ALTER USER MAPPING | Y | Y | DDL |
ALTER VIEW | Y | Y | DDL |
ANALYZE | Y | N | N |
BEGIN | Y | N | N |
CHECKPOINT | Y | N | N |
CLOSE | Y | N | N |
CLOSE CURSOR | Y | N | N |
CLOSE CURSOR ALL | Y | N | N |
CLUSTER | Y | N | N |
COMMENT | Y | Details | DDL |
COMMIT | Y | N | N |
COMMIT PREPARED | Y | N | N |
COPY | Y | N | N |
COPY FROM | Y | N | N |
CREATE ACCESS METHOD | Y | Y | DDL |
CREATE AGGREGATE | Y | Y | DDL |
CREATE CAST | Y | Y | DDL |
CREATE COLLATION | Y | Y | DDL |
CREATE CONSTRAINT | Y | Y | DDL |
CREATE CONVERSION | Y | Y | DDL |
CREATE DATABASE | Y | N | N |
CREATE DATABASE LINK | Y | Y | DDL |
CREATE DIRECTORY | Y | Y | DDL |
CREATE DOMAIN | Y | Y | DDL |
CREATE EVENT TRIGGER | Y | Y | DDL |
CREATE EXTENSION | Y | Y | DDL |
CREATE FOREIGN DATA WRAPPER | Y | Y | DDL |
CREATE FOREIGN TABLE | Y | Y | DDL |
CREATE FUNCTION | Y | Y | DDL |
CREATE INDEX | Y | Y | DML |
CREATE LANGUAGE | Y | Y | DDL |
CREATE MATERIALIZED VIEW | Y | N | N |
CREATE OPERATOR | Y | Y | DDL |
CREATE OPERATOR CLASS | Y | Y | DDL |
CREATE OPERATOR FAMILY | Y | Y | DDL |
CREATE PACKAGE | Y | Y | DDL |
CREATE PACKAGE BODY | Y | Y | DDL |
CREATE POLICY | Y | Y | DML |
CREATE PROCEDURE | Y | Y | DDL |
CREATE PROFILE | Y | Y | Details |
CREATE PUBLICATION | Y | Y | DDL |
CREATE QUEUE | Y | Y | DDL |
CREATE QUEUE TABLE | Y | Y | DDL |
CREATE REDACTION POLICY | Y | Y | DDL |
CREATE RESOURCE GROUP | Y | N | N |
CREATE ROLE | Y | Y | DDL |
CREATE ROUTINE | Y | Y | DDL |
CREATE RULE | Y | Y | DDL |
CREATE SCHEMA | Y | Y | DDL |
CREATE SEQUENCE | Details | Y | DDL |
CREATE SERVER | Y | Y | DDL |
CREATE STATISTICS | Y | Y | DDL |
CREATE SUBSCRIPTION | Y | Y | DDL |
CREATE SYNONYM | Y | Y | DDL |
CREATE TABLE | Details | Y | DDL |
CREATE TABLE AS | Details | Y | DDL |
CREATE TABLESPACE | Y | N | N |
CREATE TEXT SEARCH CONFIGURATION | Y | Y | DDL |
CREATE TEXT SEARCH DICTIONARY | Y | Y | DDL |
CREATE TEXT SEARCH PARSER | Y | Y | DDL |
CREATE TEXT SEARCH TEMPLATE | Y | Y | DDL |
CREATE TRANSFORM | Y | Y | DDL |
CREATE TRIGGER | Y | Y | DDL |
CREATE TYPE | Y | Y | DDL |
CREATE TYPE BODY | Y | Y | DDL |
CREATE USER MAPPING | Y | Y | DDL |
CREATE VIEW | Y | Y | DDL |
DEALLOCATE | Y | N | N |
DEALLOCATE ALL | Y | N | N |
DECLARE CURSOR | Y | N | N |
DISCARD | Y | N | N |
DISCARD ALL | Y | N | N |
DISCARD PLANS | Y | N | N |
DISCARD SEQUENCES | Y | N | N |
DISCARD TEMP | Y | N | N |
DO | Y | N | N |
DROP ACCESS METHOD | Y | Y | DDL |
DROP AGGREGATE | Y | Y | DDL |
DROP CAST | Y | Y | DDL |
DROP COLLATION | Y | Y | DDL |
DROP CONSTRAINT | Y | Y | DDL |
DROP CONVERSION | Y | Y | DDL |
DROP DATABASE | Y | N | N |
DROP DATABASE LINK | Y | Y | DDL |
DROP DIRECTORY | Y | Y | DDL |
DROP DOMAIN | Y | Y | DDL |
DROP EVENT TRIGGER | Y | Y | DDL |
DROP EXTENSION | Y | Y | DDL |
DROP FOREIGN DATA WRAPPER | Y | Y | DDL |
DROP FOREIGN TABLE | Y | Y | DDL |
DROP FUNCTION | Y | Y | DDL |
DROP INDEX | Y | Y | DDL |
DROP LANGUAGE | Y | Y | DDL |
DROP MATERIALIZED VIEW | Y | N | N |
DROP OPERATOR | Y | Y | DDL |
DROP OPERATOR CLASS | Y | Y | DDL |
DROP OPERATOR FAMILY | Y | Y | DDL |
DROP OWNED | Y | Y | DDL |
DROP PACKAGE | Y | Y | DDL |
DROP PACKAGE BODY | Y | Y | DDL |
DROP POLICY | Y | Y | DDL |
DROP PROCEDURE | Y | Y | DDL |
DROP PROFILE | Y | Y | DDL |
DROP PUBLICATION | Y | Y | DDL |
DROP QUEUE | Y | Y | DDL |
DROP QUEUE TABLE | Y | Y | DDL |
DROP REDACTION POLICY | Y | Y | DDL |
DROP RESOURCE GROUP | Y | N | N |
DROP ROLE | Y | Y | DDL |
DROP ROUTINE | Y | Y | DDL |
DROP RULE | Y | Y | DDL |
DROP SCHEMA | Y | Y | DDL |
DROP SEQUENCE | Y | Y | DDL |
DROP SERVER | Y | Y | DDL |
DROP STATISTICS | Y | Y | DDL |
DROP SUBSCRIPTION | Y | Y | DDL |
DROP SYNONYM | Y | Y | DDL |
DROP TABLE | Y | Y | DML |
DROP TABLESPACE | Y | N | N |
DROP TEXT SEARCH CONFIGURATION | Y | Y | DDL |
DROP TEXT SEARCH DICTIONARY | Y | Y | DDL |
DROP TEXT SEARCH PARSER | Y | Y | DDL |
DROP TEXT SEARCH TEMPLATE | Y | Y | DDL |
DROP TRANSFORM | Y | Y | DDL |
DROP TRIGGER | Y | Y | DDL |
DROP TYPE | Y | Y | DDL |
DROP TYPE BODY | Y | Y | DDL |
DROP USER MAPPING | Y | Y | DDL |
DROP VIEW | Y | Y | DDL |
EXECUTE | Y | N | N |
EXPLAIN | Y | Details | Details |
FETCH | Y | N | N |
GRANT | Y | Details | DDL |
GRANT ROLE | Y | Y | DDL |
IMPORT FOREIGN SCHEMA | Y | Y | DDL |
LISTEN | Y | N | N |
LOAD | Y | N | N |
LOAD ROW DATA | Y | Y | DDL |
LOCK TABLE | Y | N | Details |
MOVE | Y | N | N |
NOTIFY | Y | N | N |
PREPARE | Y | N | N |
PREPARE TRANSACTION | Y | N | N |
REASSIGN OWNED | Y | Y | DDL |
REFRESH MATERIALIZED VIEW | Y | N | N |
REINDEX | Y | N | N |
RELEASE | Y | N | N |
RESET | Y | N | N |
REVOKE | Y | Details | DDL |
REVOKE ROLE | Y | Y | DDL |
ROLLBACK | Y | N | N |
ROLLBACK PREPARED | Y | N | N |
SAVEPOINT | Y | N | N |
SECURITY LABEL | Y | Details | DDL |
SELECT INTO | Details | Y | DDL |
SET | Y | N | N |
SET CONSTRAINTS | Y | N | N |
SHOW | Y | N | N |
START TRANSACTION | Y | N | N |
TRUNCATE TABLE | Y | Details | Details |
UNLISTEN | Y | N | N |
VACUUM | Y | N | N |
Command Notes
ALTER SEQUENCE
Generally ALTER SEQUENCE
is supported, but when using global
sequences, some options have no effect.
ALTER SEQUENCE ... RENAME
isn't supported on galloc sequences (only).
ALTER SEQUENCE ... SET SCHEMA
isn't supported on galloc sequences (only).
ALTER TABLE
Generally, ALTER TABLE
commands are allowed. However, several
subcommands aren't supported.
ALTER TABLE disallowed commands
Some variants of ALTER TABLE
currently aren't allowed on a PGD node:
ADD COLUMN ... DEFAULT (non-immutable expression)
— This is not allowed because it currently results in different data on different nodes. See Adding a column for a suggested workaround.ADD CONSTRAINT ... EXCLUDE
— Exclusion constraints are not supported. Exclusion constraints are a way to ensure that no two rows in a table have overlapping ranges. This is useful in a synchronous system where you can ensure that the constraint is enforced on all nodes at the same time. But in an asynchronous system, you can't ensure that the constraint is enforced on all nodes at the same time. This can lead to data inconsistency and changes that can't be replayed; therefore, exclusion constraints aren't supported.ALTER TABLE ... SET WITH[OUT] OIDS
— Isn't supported for the same reasons as inCREATE TABLE
.ALTER COLUMN ... SET STORAGE external
— Is rejected if the column is one of the columns of the replica identity for the table.RENAME
— Can't rename an Autopartitioned table.SET SCHEMA
— Can't set the schema of an Autopartitioned table.ALTER COLUMN ... TYPE
— Changing a column's type isn't supported if the command causes the whole table to be rewritten, which occurs when the change isn't binary coercible. Binary coercible changes might be allowed only one way. For example, the change fromVARCHAR(128)
toVARCHAR(256)
is binary coercible and therefore allowed, whereas the changeVARCHAR(256)
toVARCHAR(128)
isn't binary coercible and therefore normally disallowed. NonreplicatedALTER COLUMN ... TYPE
, can be allowed if the column is automatically castable to the new type (it doesn't contain theUSING
clause). An example follows. Table rewrites hold an AccessExclusiveLock for extended periods on larger tables, so such commands are likely to be infeasible on highly available databases in any case. See Changing a column's type for a suggested workaround.ALTER TABLE ... ADD FOREIGN KEY
— Isn't supported if current user doesn't have permission to read the referenced table or if the referenced table has RLS restrictions enabled that the current user can't bypass.
The following example fails because it tries to add a constant value of type timestamp
onto a column of type timestamptz
. The cast between timestamp
and timestamptz
relies on the time zone of the session and so isn't immutable.
Starting in PGD 3.7.4, you can add certain types of constraints, such as CHECK
and
FOREIGN KEY
constraints, without taking a DML lock. But
this requires a two-step process of first creating a NOT VALID
constraint
and then validating the constraint in a separate transaction with the ALTER TABLE ... VALIDATE CONSTRAINT
command. See Adding a CONSTRAINT
for more details.
ALTER TABLE locking
The following variants of ALTER TABLE
take only DDL lock and not a
DML lock:
ALTER TABLE ... ADD COLUMN ... (immutable) DEFAULT
ALTER TABLE ... ALTER COLUMN ... SET DEFAULT expression
ALTER TABLE ... ALTER COLUMN ... DROP DEFAULT
ALTER TABLE ... ALTER COLUMN ... TYPE
if it doesn't require rewriteALTER TABLE ... ALTER COLUMN ... SET STATISTICS
ALTER TABLE ... VALIDATE CONSTRAINT
ALTER TABLE ... ATTACH PARTITION
ALTER TABLE ... DETACH PARTITION
ALTER TABLE ... ENABLE TRIGGER
(ENABLE REPLICA TRIGGER
still takes a DML lock)ALTER TABLE ... CLUSTER ON
ALTER TABLE ... SET WITHOUT CLUSTER
ALTER TABLE ... SET ( storage_parameter = value [, ... ] )
ALTER TABLE ... RESET ( storage_parameter = [, ... ] )
ALTER TABLE ... OWNER TO
All other variants of ALTER TABLE
take a DML lock on the table being modified.
Some variants of ALTER TABLE
have restrictions, noted below.
ALTER TABLE examples
This next example works because the type change is binary coercible and so doesn't cause a table rewrite. It executes as a catalog-only change.
However, making this change to reverse the command isn't possible because
the change from VARCHAR(128)
to VARCHAR(20)
isn't binary coercible.
For workarounds, see Restricted DDL workarounds.
It's useful to provide context for different types of ALTER TABLE ...
ALTER COLUMN TYPE
(ATCT) operations that are possible in general and in
nonreplicated environments.
Some ATCT operations update only the metadata of the underlying column type and don't require a rewrite of the underlying table data. This is typically the case when the existing column type and the target type are binary coercible. For example:
You can also change the column type to VARCHAR
or TEXT
data types because of binary coercibility. Again, this is just a metadata
update of the underlying column type.
However, if you want to reduce the size of col2, then that leads to a rewrite of the underlying table data. Rewrite of a table is normally restricted.
To give an example with nontext types, consider col3 above with type INTEGER. An ATCT operation that tries to convert to SMALLINT or BIGINT fails in a similar manner as above.
In both of these failing cases, there's an automatic assignment cast from the current types to the target types. However, there's no binary coercibility, which ends up causing a rewrite of the underlying table data.
In such cases, in controlled DBA environments, you can change the type of a column to an automatically castable one by adopting a rolling upgrade for the type of this column in a nonreplicated environment on all the nodes, one by one. Suppose the DDL isn't replicated and the change of the column type is to an automatically castable one. You can then allow the rewrite locally on the node performing the alter, along with concurrent activity on other nodes on this same table. You can then repeat this nonreplicated ATCT operation on all the nodes one by one to bring about the desired change of the column type across the entire EDB Postgres Distributed cluster. Because this involves a rewrite, the activity still takes the DML lock for a brief period and thus requires that the whole cluster is available. With these specifics in place, you can carry out the rolling upgrade of the nonreplicated alter activity like this:
Due to automatic assignment casts being available for many data types,
this local nonreplicated ATCT operation supports a wide variety of
conversions. Also, ATCT operations that use a USING
clause
are likely to fail because of the lack of automatic assignment casts.
This example shows a few common conversions with automatic assignment casts:
This example isn't an exhaustive list of possibly allowable ATCT operations in a nonreplicated environment. Not all ATCT operations work. The cases where no automatic assignment is possible fail even if you disable DDL replication. So, while conversion from numeric types to text types works in a nonreplicated environment, conversion back from text type to numeric types fails.
While the ATCT operations in nonreplicated environments support a
variety of type conversions, the rewrite
can still fail if the underlying table data contains values that you can't
assign to the new data type. For example, suppose the current type for
a column is VARCHAR(256)
and you try a nonreplicated ATCT
operation to convert it into VARCHAR(128)
. If there's any existing data
in the table that's wider than 128 bytes, then the rewrite operation
fails locally.
If underlying table data meets the characteristics of the new type, then the rewrite succeeds. However, replication might fail if other nodes that haven't yet performed the nonreplicated rolling data type upgrade introduce new data that is wider than 128 bytes concurrently to this local ATCT operation. This brings replication to a halt in the cluster. So be aware of the data type restrictions and characteristics at the database and application levels while performing these nonreplicated rolling data type upgrade operations. We strongly recommend that you perform and test such ATCT operations in controlled and fully aware DBA environments. These ATCT operations are asymmetric, and backing out certain changes that fail can lead to table rewrites that take a long time.
Also, you can't perform the implicit castable ALTER activity in transaction blocks.
ALTER TYPE
ALTER TYPE
is replicated, but a global DML lock isn't
applied to all tables that use that data type, since PostgreSQL doesn't
record those dependencies. See Restricted DDL workarounds.
COMMENT ON
All variants of COMMENT ON
are allowed, but
COMMENT ON TABLESPACE/DATABASE/LARGE OBJECT
isn't replicated.
CREATE PROFILE or ALTER PROFILE
The PASSWORD_VERIFY_FUNCTION
associated with the profile should be IMMUTABLE
if the function is SECURITY DEFINER
.
Such a CREATE PROFILE
or ALTER PROFILE
command will be replicated but subsequent CREATE USER
or ALTER USER
commands using this profile will
break the replication due to the writer
worker throwing the error: cannot change current role within security-restricted operation
.
CREATE SEQUENCE
Generally CREATE SEQUENCE
is supported, but when using global
sequences, some options have no effect.
CREATE TABLE
Generally CREATE TABLE
is supported, but CREATE TABLE WITH OIDS
isn't
allowed on a PGD node.
CREATE TABLE AS and SELECT INTO
CREATE TABLE AS
and SELECT INTO
are allowed only if all subcommands are
also allowed.
EXPLAIN
Generally EXPLAIN
is allowed, but because EXPLAIN ANALYZE
can have side
effects on the database, there are some restrictions on it.
EXPLAIN ANALYZE Replication
EXPLAIN ANALYZE
follows replication rules of the analyzed statement.
EXPLAIN ANALYZE Locking
EXPLAIN ANALYZE
follows locking rules of the analyzed statement.
GRANT and REVOKE
Generally GRANT
and REVOKE
statements are supported, however
GRANT/REVOKE ON TABLESPACE/LARGE OBJECT
aren't replicated.
LOCK TABLE
LOCK TABLE isn't replicated, but it might acquire the global DML lock when
bdr.lock_table_locking
is set on
.
You can also use The bdr.global_lock_table()
function to explicitly request a global DML
lock.
SECURITY LABEL
All variants of SECURITY LABEL
are allowed, but
SECURITY LABEL ON TABLESPACE/DATABASE/LARGE OBJECT
isn't replicated.
TRUNCATE Replication
TRUNCATE
command is replicated as DML, not as a DDL statement. Whether
the TRUNCATE
on table is replicated depends on replication settings for
each affected table.
TRUNCATE Locking
Even though TRUNCATE
isn't replicated the same way as other DDL, it can acquire
the global DML lock when bdr.truncate_locking
is set to on
.