From e89093faf7225a635ddb5d4f260b20a4d8dd64e2 Mon Sep 17 00:00:00 2001 From: Marius Posta Date: Wed, 6 Oct 2021 20:12:02 -0400 Subject: [PATCH] sql: Add IF NOT EXISTS modifier to ALTER TABLE ... ADD CONSTRAINT Previously, it was not possible to execute ALTER TABLE ... ADD CONSTRAINT IF NOT EXISTS ... statements. This commit adds this IF NOT EXISTS modifier to the ADD CONSTRAINT command of the ALTER TABLE statement. When the modifier is present and the defined constraint name already exists in the table, the statement no-ops instead of erroring. Note that this syntax is not supported in PostgreSQL, however PostgreSQL has transactional schema changes and PL/pgSQL which make it possible to achieve the same thing. CockroachDB has none of that yet. This commit also fixes some minor bugs or inconsistencies in the handling of duplicate index names. Fixes #53007. Release note (sql change): added ALTER TABLE ... ADD CONSTRAINT IF NOT EXISTS. --- docs/generated/sql/bnf/alter_table.bnf | 4 +- .../sql/bnf/alter_table_partition_by.bnf | 4 +- docs/generated/sql/bnf/stmt_block.bnf | 55 +++++------ pkg/sql/alter_primary_key.go | 2 +- pkg/sql/alter_table.go | 95 ++++++++++++++++--- pkg/sql/catalog/tabledesc/BUILD.bazel | 1 - pkg/sql/catalog/tabledesc/structured.go | 11 --- pkg/sql/create_index.go | 8 +- pkg/sql/create_table.go | 12 ++- pkg/sql/descriptor_mutation_test.go | 7 +- .../testdata/logic_test/alter_primary_key | 32 +++++-- .../logictest/testdata/logic_test/alter_table | 23 ++++- .../testdata/logic_test/create_index | 2 +- pkg/sql/opt/exec/execbuilder/testdata/ddl | 2 +- pkg/sql/parser/sql.y | 11 +++ pkg/sql/sem/tree/create.go | 49 ++++++++-- 16 files changed, 231 insertions(+), 87 deletions(-) diff --git a/docs/generated/sql/bnf/alter_table.bnf b/docs/generated/sql/bnf/alter_table.bnf index d61ecaed55df..303f85d9a7ff 100644 --- a/docs/generated/sql/bnf/alter_table.bnf +++ b/docs/generated/sql/bnf/alter_table.bnf @@ -1,3 +1,3 @@ alter_onetable_stmt ::= - 'ALTER' 'TABLE' table_name ( ( ( 'RENAME' ( 'COLUMN' | ) column_name 'TO' column_name | 'RENAME' 'CONSTRAINT' column_name 'TO' column_name | 'ADD' ( column_name typename col_qual_list ) | 'ADD' 'IF' 'NOT' 'EXISTS' ( column_name typename col_qual_list ) | 'ADD' 'COLUMN' ( column_name typename col_qual_list ) | 'ADD' 'COLUMN' 'IF' 'NOT' 'EXISTS' ( column_name typename col_qual_list ) | 'ALTER' ( 'COLUMN' | ) column_name ( 'SET' 'DEFAULT' a_expr | 'DROP' 'DEFAULT' ) | 'ALTER' ( 'COLUMN' | ) column_name alter_column_on_update | 'ALTER' ( 'COLUMN' | ) column_name alter_column_visible | 'ALTER' ( 'COLUMN' | ) column_name 'DROP' 'NOT' 'NULL' | 'ALTER' ( 'COLUMN' | ) column_name 'DROP' 'STORED' | 'ALTER' ( 'COLUMN' | ) column_name 'SET' 'NOT' 'NULL' | 'DROP' ( 'COLUMN' | ) 'IF' 'EXISTS' column_name ( 'CASCADE' | 'RESTRICT' | ) | 'DROP' ( 'COLUMN' | ) column_name ( 'CASCADE' | 'RESTRICT' | ) | 'ALTER' ( 'COLUMN' | ) column_name ( 'SET' 'DATA' | ) 'TYPE' typename ( 'COLLATE' collation_name | ) ( 'USING' a_expr | ) | 'ADD' ( 'CONSTRAINT' constraint_name constraint_elem | constraint_elem ) | 'ALTER' 'PRIMARY' 'KEY' 'USING' 'COLUMNS' '(' index_params ')' opt_hash_sharded | 'VALIDATE' 'CONSTRAINT' constraint_name | 'DROP' 'CONSTRAINT' 'IF' 'EXISTS' constraint_name ( 'CASCADE' | 'RESTRICT' | ) | 'DROP' 'CONSTRAINT' constraint_name ( 'CASCADE' | 'RESTRICT' | ) | 'EXPERIMENTAL_AUDIT' 'SET' audit_mode | partition_by_table ) ) ( ( ',' ( 'RENAME' ( 'COLUMN' | ) column_name 'TO' column_name | 'RENAME' 'CONSTRAINT' column_name 'TO' column_name | 'ADD' ( column_name typename col_qual_list ) | 'ADD' 'IF' 'NOT' 'EXISTS' ( column_name typename col_qual_list ) | 'ADD' 'COLUMN' ( column_name typename col_qual_list ) | 'ADD' 'COLUMN' 'IF' 'NOT' 'EXISTS' ( column_name typename col_qual_list ) | 'ALTER' ( 'COLUMN' | ) column_name ( 'SET' 'DEFAULT' a_expr | 'DROP' 'DEFAULT' ) | 'ALTER' ( 'COLUMN' | ) column_name alter_column_on_update | 'ALTER' ( 'COLUMN' | ) column_name alter_column_visible | 'ALTER' ( 'COLUMN' | ) column_name 'DROP' 'NOT' 'NULL' | 'ALTER' ( 'COLUMN' | ) column_name 'DROP' 'STORED' | 'ALTER' ( 'COLUMN' | ) column_name 'SET' 'NOT' 'NULL' | 'DROP' ( 'COLUMN' | ) 'IF' 'EXISTS' column_name ( 'CASCADE' | 'RESTRICT' | ) | 'DROP' ( 'COLUMN' | ) column_name ( 'CASCADE' | 'RESTRICT' | ) | 'ALTER' ( 'COLUMN' | ) column_name ( 'SET' 'DATA' | ) 'TYPE' typename ( 'COLLATE' collation_name | ) ( 'USING' a_expr | ) | 'ADD' ( 'CONSTRAINT' constraint_name constraint_elem | constraint_elem ) | 'ALTER' 'PRIMARY' 'KEY' 'USING' 'COLUMNS' '(' index_params ')' opt_hash_sharded | 'VALIDATE' 'CONSTRAINT' constraint_name | 'DROP' 'CONSTRAINT' 'IF' 'EXISTS' constraint_name ( 'CASCADE' | 'RESTRICT' | ) | 'DROP' 'CONSTRAINT' constraint_name ( 'CASCADE' | 'RESTRICT' | ) | 'EXPERIMENTAL_AUDIT' 'SET' audit_mode | partition_by_table ) ) )* ) - | 'ALTER' 'TABLE' 'IF' 'EXISTS' table_name ( ( ( 'RENAME' ( 'COLUMN' | ) column_name 'TO' column_name | 'RENAME' 'CONSTRAINT' column_name 'TO' column_name | 'ADD' ( column_name typename col_qual_list ) | 'ADD' 'IF' 'NOT' 'EXISTS' ( column_name typename col_qual_list ) | 'ADD' 'COLUMN' ( column_name typename col_qual_list ) | 'ADD' 'COLUMN' 'IF' 'NOT' 'EXISTS' ( column_name typename col_qual_list ) | 'ALTER' ( 'COLUMN' | ) column_name ( 'SET' 'DEFAULT' a_expr | 'DROP' 'DEFAULT' ) | 'ALTER' ( 'COLUMN' | ) column_name alter_column_on_update | 'ALTER' ( 'COLUMN' | ) column_name alter_column_visible | 'ALTER' ( 'COLUMN' | ) column_name 'DROP' 'NOT' 'NULL' | 'ALTER' ( 'COLUMN' | ) column_name 'DROP' 'STORED' | 'ALTER' ( 'COLUMN' | ) column_name 'SET' 'NOT' 'NULL' | 'DROP' ( 'COLUMN' | ) 'IF' 'EXISTS' column_name ( 'CASCADE' | 'RESTRICT' | ) | 'DROP' ( 'COLUMN' | ) column_name ( 'CASCADE' | 'RESTRICT' | ) | 'ALTER' ( 'COLUMN' | ) column_name ( 'SET' 'DATA' | ) 'TYPE' typename ( 'COLLATE' collation_name | ) ( 'USING' a_expr | ) | 'ADD' ( 'CONSTRAINT' constraint_name constraint_elem | constraint_elem ) | 'ALTER' 'PRIMARY' 'KEY' 'USING' 'COLUMNS' '(' index_params ')' opt_hash_sharded | 'VALIDATE' 'CONSTRAINT' constraint_name | 'DROP' 'CONSTRAINT' 'IF' 'EXISTS' constraint_name ( 'CASCADE' | 'RESTRICT' | ) | 'DROP' 'CONSTRAINT' constraint_name ( 'CASCADE' | 'RESTRICT' | ) | 'EXPERIMENTAL_AUDIT' 'SET' audit_mode | partition_by_table ) ) ( ( ',' ( 'RENAME' ( 'COLUMN' | ) column_name 'TO' column_name | 'RENAME' 'CONSTRAINT' column_name 'TO' column_name | 'ADD' ( column_name typename col_qual_list ) | 'ADD' 'IF' 'NOT' 'EXISTS' ( column_name typename col_qual_list ) | 'ADD' 'COLUMN' ( column_name typename col_qual_list ) | 'ADD' 'COLUMN' 'IF' 'NOT' 'EXISTS' ( column_name typename col_qual_list ) | 'ALTER' ( 'COLUMN' | ) column_name ( 'SET' 'DEFAULT' a_expr | 'DROP' 'DEFAULT' ) | 'ALTER' ( 'COLUMN' | ) column_name alter_column_on_update | 'ALTER' ( 'COLUMN' | ) column_name alter_column_visible | 'ALTER' ( 'COLUMN' | ) column_name 'DROP' 'NOT' 'NULL' | 'ALTER' ( 'COLUMN' | ) column_name 'DROP' 'STORED' | 'ALTER' ( 'COLUMN' | ) column_name 'SET' 'NOT' 'NULL' | 'DROP' ( 'COLUMN' | ) 'IF' 'EXISTS' column_name ( 'CASCADE' | 'RESTRICT' | ) | 'DROP' ( 'COLUMN' | ) column_name ( 'CASCADE' | 'RESTRICT' | ) | 'ALTER' ( 'COLUMN' | ) column_name ( 'SET' 'DATA' | ) 'TYPE' typename ( 'COLLATE' collation_name | ) ( 'USING' a_expr | ) | 'ADD' ( 'CONSTRAINT' constraint_name constraint_elem | constraint_elem ) | 'ALTER' 'PRIMARY' 'KEY' 'USING' 'COLUMNS' '(' index_params ')' opt_hash_sharded | 'VALIDATE' 'CONSTRAINT' constraint_name | 'DROP' 'CONSTRAINT' 'IF' 'EXISTS' constraint_name ( 'CASCADE' | 'RESTRICT' | ) | 'DROP' 'CONSTRAINT' constraint_name ( 'CASCADE' | 'RESTRICT' | ) | 'EXPERIMENTAL_AUDIT' 'SET' audit_mode | partition_by_table ) ) )* ) + 'ALTER' 'TABLE' table_name ( ( ( 'RENAME' ( 'COLUMN' | ) column_name 'TO' column_name | 'RENAME' 'CONSTRAINT' column_name 'TO' column_name | 'ADD' ( column_name typename col_qual_list ) | 'ADD' 'IF' 'NOT' 'EXISTS' ( column_name typename col_qual_list ) | 'ADD' 'COLUMN' ( column_name typename col_qual_list ) | 'ADD' 'COLUMN' 'IF' 'NOT' 'EXISTS' ( column_name typename col_qual_list ) | 'ALTER' ( 'COLUMN' | ) column_name ( 'SET' 'DEFAULT' a_expr | 'DROP' 'DEFAULT' ) | 'ALTER' ( 'COLUMN' | ) column_name alter_column_on_update | 'ALTER' ( 'COLUMN' | ) column_name alter_column_visible | 'ALTER' ( 'COLUMN' | ) column_name 'DROP' 'NOT' 'NULL' | 'ALTER' ( 'COLUMN' | ) column_name 'DROP' 'STORED' | 'ALTER' ( 'COLUMN' | ) column_name 'SET' 'NOT' 'NULL' | 'DROP' ( 'COLUMN' | ) 'IF' 'EXISTS' column_name ( 'CASCADE' | 'RESTRICT' | ) | 'DROP' ( 'COLUMN' | ) column_name ( 'CASCADE' | 'RESTRICT' | ) | 'ALTER' ( 'COLUMN' | ) column_name ( 'SET' 'DATA' | ) 'TYPE' typename ( 'COLLATE' collation_name | ) ( 'USING' a_expr | ) | 'ADD' ( 'CONSTRAINT' constraint_name constraint_elem | constraint_elem ) | 'ADD' 'CONSTRAINT' 'IF' 'NOT' 'EXISTS' constraint_name constraint_elem | 'ALTER' 'PRIMARY' 'KEY' 'USING' 'COLUMNS' '(' index_params ')' opt_hash_sharded | 'VALIDATE' 'CONSTRAINT' constraint_name | 'DROP' 'CONSTRAINT' 'IF' 'EXISTS' constraint_name ( 'CASCADE' | 'RESTRICT' | ) | 'DROP' 'CONSTRAINT' constraint_name ( 'CASCADE' | 'RESTRICT' | ) | 'EXPERIMENTAL_AUDIT' 'SET' audit_mode | partition_by_table ) ) ( ( ',' ( 'RENAME' ( 'COLUMN' | ) column_name 'TO' column_name | 'RENAME' 'CONSTRAINT' column_name 'TO' column_name | 'ADD' ( column_name typename col_qual_list ) | 'ADD' 'IF' 'NOT' 'EXISTS' ( column_name typename col_qual_list ) | 'ADD' 'COLUMN' ( column_name typename col_qual_list ) | 'ADD' 'COLUMN' 'IF' 'NOT' 'EXISTS' ( column_name typename col_qual_list ) | 'ALTER' ( 'COLUMN' | ) column_name ( 'SET' 'DEFAULT' a_expr | 'DROP' 'DEFAULT' ) | 'ALTER' ( 'COLUMN' | ) column_name alter_column_on_update | 'ALTER' ( 'COLUMN' | ) column_name alter_column_visible | 'ALTER' ( 'COLUMN' | ) column_name 'DROP' 'NOT' 'NULL' | 'ALTER' ( 'COLUMN' | ) column_name 'DROP' 'STORED' | 'ALTER' ( 'COLUMN' | ) column_name 'SET' 'NOT' 'NULL' | 'DROP' ( 'COLUMN' | ) 'IF' 'EXISTS' column_name ( 'CASCADE' | 'RESTRICT' | ) | 'DROP' ( 'COLUMN' | ) column_name ( 'CASCADE' | 'RESTRICT' | ) | 'ALTER' ( 'COLUMN' | ) column_name ( 'SET' 'DATA' | ) 'TYPE' typename ( 'COLLATE' collation_name | ) ( 'USING' a_expr | ) | 'ADD' ( 'CONSTRAINT' constraint_name constraint_elem | constraint_elem ) | 'ADD' 'CONSTRAINT' 'IF' 'NOT' 'EXISTS' constraint_name constraint_elem | 'ALTER' 'PRIMARY' 'KEY' 'USING' 'COLUMNS' '(' index_params ')' opt_hash_sharded | 'VALIDATE' 'CONSTRAINT' constraint_name | 'DROP' 'CONSTRAINT' 'IF' 'EXISTS' constraint_name ( 'CASCADE' | 'RESTRICT' | ) | 'DROP' 'CONSTRAINT' constraint_name ( 'CASCADE' | 'RESTRICT' | ) | 'EXPERIMENTAL_AUDIT' 'SET' audit_mode | partition_by_table ) ) )* ) + | 'ALTER' 'TABLE' 'IF' 'EXISTS' table_name ( ( ( 'RENAME' ( 'COLUMN' | ) column_name 'TO' column_name | 'RENAME' 'CONSTRAINT' column_name 'TO' column_name | 'ADD' ( column_name typename col_qual_list ) | 'ADD' 'IF' 'NOT' 'EXISTS' ( column_name typename col_qual_list ) | 'ADD' 'COLUMN' ( column_name typename col_qual_list ) | 'ADD' 'COLUMN' 'IF' 'NOT' 'EXISTS' ( column_name typename col_qual_list ) | 'ALTER' ( 'COLUMN' | ) column_name ( 'SET' 'DEFAULT' a_expr | 'DROP' 'DEFAULT' ) | 'ALTER' ( 'COLUMN' | ) column_name alter_column_on_update | 'ALTER' ( 'COLUMN' | ) column_name alter_column_visible | 'ALTER' ( 'COLUMN' | ) column_name 'DROP' 'NOT' 'NULL' | 'ALTER' ( 'COLUMN' | ) column_name 'DROP' 'STORED' | 'ALTER' ( 'COLUMN' | ) column_name 'SET' 'NOT' 'NULL' | 'DROP' ( 'COLUMN' | ) 'IF' 'EXISTS' column_name ( 'CASCADE' | 'RESTRICT' | ) | 'DROP' ( 'COLUMN' | ) column_name ( 'CASCADE' | 'RESTRICT' | ) | 'ALTER' ( 'COLUMN' | ) column_name ( 'SET' 'DATA' | ) 'TYPE' typename ( 'COLLATE' collation_name | ) ( 'USING' a_expr | ) | 'ADD' ( 'CONSTRAINT' constraint_name constraint_elem | constraint_elem ) | 'ADD' 'CONSTRAINT' 'IF' 'NOT' 'EXISTS' constraint_name constraint_elem | 'ALTER' 'PRIMARY' 'KEY' 'USING' 'COLUMNS' '(' index_params ')' opt_hash_sharded | 'VALIDATE' 'CONSTRAINT' constraint_name | 'DROP' 'CONSTRAINT' 'IF' 'EXISTS' constraint_name ( 'CASCADE' | 'RESTRICT' | ) | 'DROP' 'CONSTRAINT' constraint_name ( 'CASCADE' | 'RESTRICT' | ) | 'EXPERIMENTAL_AUDIT' 'SET' audit_mode | partition_by_table ) ) ( ( ',' ( 'RENAME' ( 'COLUMN' | ) column_name 'TO' column_name | 'RENAME' 'CONSTRAINT' column_name 'TO' column_name | 'ADD' ( column_name typename col_qual_list ) | 'ADD' 'IF' 'NOT' 'EXISTS' ( column_name typename col_qual_list ) | 'ADD' 'COLUMN' ( column_name typename col_qual_list ) | 'ADD' 'COLUMN' 'IF' 'NOT' 'EXISTS' ( column_name typename col_qual_list ) | 'ALTER' ( 'COLUMN' | ) column_name ( 'SET' 'DEFAULT' a_expr | 'DROP' 'DEFAULT' ) | 'ALTER' ( 'COLUMN' | ) column_name alter_column_on_update | 'ALTER' ( 'COLUMN' | ) column_name alter_column_visible | 'ALTER' ( 'COLUMN' | ) column_name 'DROP' 'NOT' 'NULL' | 'ALTER' ( 'COLUMN' | ) column_name 'DROP' 'STORED' | 'ALTER' ( 'COLUMN' | ) column_name 'SET' 'NOT' 'NULL' | 'DROP' ( 'COLUMN' | ) 'IF' 'EXISTS' column_name ( 'CASCADE' | 'RESTRICT' | ) | 'DROP' ( 'COLUMN' | ) column_name ( 'CASCADE' | 'RESTRICT' | ) | 'ALTER' ( 'COLUMN' | ) column_name ( 'SET' 'DATA' | ) 'TYPE' typename ( 'COLLATE' collation_name | ) ( 'USING' a_expr | ) | 'ADD' ( 'CONSTRAINT' constraint_name constraint_elem | constraint_elem ) | 'ADD' 'CONSTRAINT' 'IF' 'NOT' 'EXISTS' constraint_name constraint_elem | 'ALTER' 'PRIMARY' 'KEY' 'USING' 'COLUMNS' '(' index_params ')' opt_hash_sharded | 'VALIDATE' 'CONSTRAINT' constraint_name | 'DROP' 'CONSTRAINT' 'IF' 'EXISTS' constraint_name ( 'CASCADE' | 'RESTRICT' | ) | 'DROP' 'CONSTRAINT' constraint_name ( 'CASCADE' | 'RESTRICT' | ) | 'EXPERIMENTAL_AUDIT' 'SET' audit_mode | partition_by_table ) ) )* ) diff --git a/docs/generated/sql/bnf/alter_table_partition_by.bnf b/docs/generated/sql/bnf/alter_table_partition_by.bnf index 491af0c610a5..75d1c8f5450e 100644 --- a/docs/generated/sql/bnf/alter_table_partition_by.bnf +++ b/docs/generated/sql/bnf/alter_table_partition_by.bnf @@ -1,3 +1,3 @@ alter_onetable_stmt ::= - 'ALTER' 'TABLE' table_name 'PARTITION' 'ALL' 'BY' partition_by_inner ( ( ',' ( 'RENAME' opt_column column_name 'TO' column_name | 'RENAME' 'CONSTRAINT' column_name 'TO' column_name | 'ADD' column_def | 'ADD' 'IF' 'NOT' 'EXISTS' column_def | 'ADD' 'COLUMN' column_def | 'ADD' 'COLUMN' 'IF' 'NOT' 'EXISTS' column_def | 'ALTER' opt_column column_name alter_column_default | 'ALTER' opt_column column_name alter_column_on_update | 'ALTER' opt_column column_name alter_column_visible | 'ALTER' opt_column column_name 'DROP' 'NOT' 'NULL' | 'ALTER' opt_column column_name 'DROP' 'STORED' | 'ALTER' opt_column column_name 'SET' 'NOT' 'NULL' | 'DROP' opt_column 'IF' 'EXISTS' column_name opt_drop_behavior | 'DROP' opt_column column_name opt_drop_behavior | 'ALTER' opt_column column_name opt_set_data 'TYPE' typename opt_collate opt_alter_column_using | 'ADD' table_constraint opt_validate_behavior | 'ALTER' 'PRIMARY' 'KEY' 'USING' 'COLUMNS' '(' index_params ')' opt_hash_sharded | 'VALIDATE' 'CONSTRAINT' constraint_name | 'DROP' 'CONSTRAINT' 'IF' 'EXISTS' constraint_name opt_drop_behavior | 'DROP' 'CONSTRAINT' constraint_name opt_drop_behavior | 'EXPERIMENTAL_AUDIT' 'SET' audit_mode | ( partition_by | 'PARTITION' 'ALL' 'BY' partition_by_inner ) ) ) )* - | 'ALTER' 'TABLE' 'IF' 'EXISTS' table_name 'PARTITION' 'ALL' 'BY' partition_by_inner ( ( ',' ( 'RENAME' opt_column column_name 'TO' column_name | 'RENAME' 'CONSTRAINT' column_name 'TO' column_name | 'ADD' column_def | 'ADD' 'IF' 'NOT' 'EXISTS' column_def | 'ADD' 'COLUMN' column_def | 'ADD' 'COLUMN' 'IF' 'NOT' 'EXISTS' column_def | 'ALTER' opt_column column_name alter_column_default | 'ALTER' opt_column column_name alter_column_on_update | 'ALTER' opt_column column_name alter_column_visible | 'ALTER' opt_column column_name 'DROP' 'NOT' 'NULL' | 'ALTER' opt_column column_name 'DROP' 'STORED' | 'ALTER' opt_column column_name 'SET' 'NOT' 'NULL' | 'DROP' opt_column 'IF' 'EXISTS' column_name opt_drop_behavior | 'DROP' opt_column column_name opt_drop_behavior | 'ALTER' opt_column column_name opt_set_data 'TYPE' typename opt_collate opt_alter_column_using | 'ADD' table_constraint opt_validate_behavior | 'ALTER' 'PRIMARY' 'KEY' 'USING' 'COLUMNS' '(' index_params ')' opt_hash_sharded | 'VALIDATE' 'CONSTRAINT' constraint_name | 'DROP' 'CONSTRAINT' 'IF' 'EXISTS' constraint_name opt_drop_behavior | 'DROP' 'CONSTRAINT' constraint_name opt_drop_behavior | 'EXPERIMENTAL_AUDIT' 'SET' audit_mode | ( partition_by | 'PARTITION' 'ALL' 'BY' partition_by_inner ) ) ) )* + 'ALTER' 'TABLE' table_name 'PARTITION' 'ALL' 'BY' partition_by_inner ( ( ',' ( 'RENAME' opt_column column_name 'TO' column_name | 'RENAME' 'CONSTRAINT' column_name 'TO' column_name | 'ADD' column_def | 'ADD' 'IF' 'NOT' 'EXISTS' column_def | 'ADD' 'COLUMN' column_def | 'ADD' 'COLUMN' 'IF' 'NOT' 'EXISTS' column_def | 'ALTER' opt_column column_name alter_column_default | 'ALTER' opt_column column_name alter_column_on_update | 'ALTER' opt_column column_name alter_column_visible | 'ALTER' opt_column column_name 'DROP' 'NOT' 'NULL' | 'ALTER' opt_column column_name 'DROP' 'STORED' | 'ALTER' opt_column column_name 'SET' 'NOT' 'NULL' | 'DROP' opt_column 'IF' 'EXISTS' column_name opt_drop_behavior | 'DROP' opt_column column_name opt_drop_behavior | 'ALTER' opt_column column_name opt_set_data 'TYPE' typename opt_collate opt_alter_column_using | 'ADD' table_constraint opt_validate_behavior | 'ADD' 'CONSTRAINT' 'IF' 'NOT' 'EXISTS' constraint_name constraint_elem opt_validate_behavior | 'ALTER' 'PRIMARY' 'KEY' 'USING' 'COLUMNS' '(' index_params ')' opt_hash_sharded | 'VALIDATE' 'CONSTRAINT' constraint_name | 'DROP' 'CONSTRAINT' 'IF' 'EXISTS' constraint_name opt_drop_behavior | 'DROP' 'CONSTRAINT' constraint_name opt_drop_behavior | 'EXPERIMENTAL_AUDIT' 'SET' audit_mode | ( partition_by | 'PARTITION' 'ALL' 'BY' partition_by_inner ) ) ) )* + | 'ALTER' 'TABLE' 'IF' 'EXISTS' table_name 'PARTITION' 'ALL' 'BY' partition_by_inner ( ( ',' ( 'RENAME' opt_column column_name 'TO' column_name | 'RENAME' 'CONSTRAINT' column_name 'TO' column_name | 'ADD' column_def | 'ADD' 'IF' 'NOT' 'EXISTS' column_def | 'ADD' 'COLUMN' column_def | 'ADD' 'COLUMN' 'IF' 'NOT' 'EXISTS' column_def | 'ALTER' opt_column column_name alter_column_default | 'ALTER' opt_column column_name alter_column_on_update | 'ALTER' opt_column column_name alter_column_visible | 'ALTER' opt_column column_name 'DROP' 'NOT' 'NULL' | 'ALTER' opt_column column_name 'DROP' 'STORED' | 'ALTER' opt_column column_name 'SET' 'NOT' 'NULL' | 'DROP' opt_column 'IF' 'EXISTS' column_name opt_drop_behavior | 'DROP' opt_column column_name opt_drop_behavior | 'ALTER' opt_column column_name opt_set_data 'TYPE' typename opt_collate opt_alter_column_using | 'ADD' table_constraint opt_validate_behavior | 'ADD' 'CONSTRAINT' 'IF' 'NOT' 'EXISTS' constraint_name constraint_elem opt_validate_behavior | 'ALTER' 'PRIMARY' 'KEY' 'USING' 'COLUMNS' '(' index_params ')' opt_hash_sharded | 'VALIDATE' 'CONSTRAINT' constraint_name | 'DROP' 'CONSTRAINT' 'IF' 'EXISTS' constraint_name opt_drop_behavior | 'DROP' 'CONSTRAINT' constraint_name opt_drop_behavior | 'EXPERIMENTAL_AUDIT' 'SET' audit_mode | ( partition_by | 'PARTITION' 'ALL' 'BY' partition_by_inner ) ) ) )* diff --git a/docs/generated/sql/bnf/stmt_block.bnf b/docs/generated/sql/bnf/stmt_block.bnf index 0e2cc6146e9d..97a1d37da31f 100644 --- a/docs/generated/sql/bnf/stmt_block.bnf +++ b/docs/generated/sql/bnf/stmt_block.bnf @@ -2636,6 +2636,7 @@ alter_table_cmd ::= | 'DROP' opt_column column_name opt_drop_behavior | 'ALTER' opt_column column_name opt_set_data 'TYPE' typename opt_collate opt_alter_column_using | 'ADD' table_constraint opt_validate_behavior + | 'ADD' 'CONSTRAINT' 'IF' 'NOT' 'EXISTS' constraint_name constraint_elem opt_validate_behavior | 'ALTER' 'PRIMARY' 'KEY' 'USING' 'COLUMNS' '(' index_params ')' opt_hash_sharded | 'VALIDATE' 'CONSTRAINT' constraint_name | 'DROP' 'CONSTRAINT' 'IF' 'EXISTS' constraint_name opt_drop_behavior @@ -2925,6 +2926,12 @@ opt_validate_behavior ::= 'NOT' 'VALID' | +constraint_elem ::= + 'CHECK' '(' a_expr ')' + | 'UNIQUE' '(' index_params ')' opt_storing opt_partition_by_index opt_where_clause + | 'PRIMARY' 'KEY' '(' index_params ')' opt_hash_sharded + | 'FOREIGN' 'KEY' '(' name_list ')' 'REFERENCES' table_name opt_column_list key_match reference_actions + audit_mode ::= 'READ' 'WRITE' | 'OFF' @@ -3106,11 +3113,17 @@ interval_second ::= col_qual_list ::= ( ) ( ( col_qualification ) )* -constraint_elem ::= - 'CHECK' '(' a_expr ')' - | 'UNIQUE' '(' index_params ')' opt_storing opt_partition_by_index opt_where_clause - | 'PRIMARY' 'KEY' '(' index_params ')' opt_hash_sharded - | 'FOREIGN' 'KEY' '(' name_list ')' 'REFERENCES' table_name opt_column_list key_match reference_actions +key_match ::= + 'MATCH' 'SIMPLE' + | 'MATCH' 'FULL' + | + +reference_actions ::= + reference_on_update + | reference_on_delete + | reference_on_update reference_on_delete + | reference_on_delete reference_on_update + | func_name ::= type_function_name @@ -3186,17 +3199,11 @@ col_qualification ::= | 'CREATE' 'FAMILY' | 'CREATE' 'IF' 'NOT' 'EXISTS' 'FAMILY' family_name -key_match ::= - 'MATCH' 'SIMPLE' - | 'MATCH' 'FULL' - | +reference_on_update ::= + 'ON' 'UPDATE' reference_action -reference_actions ::= - reference_on_update - | reference_on_delete - | reference_on_update reference_on_delete - | reference_on_delete reference_on_update - | +reference_on_delete ::= + 'ON' 'DELETE' reference_action type_function_name ::= 'identifier' @@ -3267,11 +3274,12 @@ col_qualification_elem ::= | generated_always_as 'IDENTITY' | generated_by_default_as 'IDENTITY' -reference_on_update ::= - 'ON' 'UPDATE' reference_action - -reference_on_delete ::= - 'ON' 'DELETE' reference_action +reference_action ::= + 'NO' 'ACTION' + | 'RESTRICT' + | 'CASCADE' + | 'SET' 'NULL' + | 'SET' 'DEFAULT' frame_extent ::= frame_bound @@ -3317,13 +3325,6 @@ generated_always_as ::= generated_by_default_as ::= 'GENERATED_BY_DEFAULT' 'BY' 'DEFAULT' 'AS' -reference_action ::= - 'NO' 'ACTION' - | 'RESTRICT' - | 'CASCADE' - | 'SET' 'NULL' - | 'SET' 'DEFAULT' - frame_bound ::= 'UNBOUNDED' 'PRECEDING' | 'UNBOUNDED' 'FOLLOWING' diff --git a/pkg/sql/alter_primary_key.go b/pkg/sql/alter_primary_key.go index adb71776aa70..4a0472a77198 100644 --- a/pkg/sql/alter_primary_key.go +++ b/pkg/sql/alter_primary_key.go @@ -157,7 +157,7 @@ func (p *planner) AlterPrimaryKey( // Allow reuse of existing primary key's name. tableDesc.PrimaryIndex.Name != string(alterPKNode.Name) && nameExists(string(alterPKNode.Name)) { - return pgerror.Newf(pgcode.DuplicateObject, "constraint with name %s already exists", alterPKNode.Name) + return pgerror.Newf(pgcode.DuplicateRelation, "index with name %s already exists", alterPKNode.Name) } newPrimaryIndexDesc := &descpb.IndexDescriptor{ Name: name, diff --git a/pkg/sql/alter_table.go b/pkg/sql/alter_table.go index 77adea737d0c..994312f34807 100644 --- a/pkg/sql/alter_table.go +++ b/pkg/sql/alter_table.go @@ -194,6 +194,11 @@ func (n *alterTableNode) startExec(params runParams) error { return err } case *tree.AlterTableAddConstraint: + if skip, err := validateConstraintNameIsNotUsed(n.tableDesc, t); err != nil { + return err + } else if skip { + continue + } switch d := t.ConstraintDef.(type) { case *tree.UniqueConstraintTableDef: if d.WithoutIndex { @@ -214,15 +219,6 @@ func (n *alterTableNode) startExec(params runParams) error { } if d.PrimaryKey { - // We only support "adding" a primary key when we are using the - // default rowid primary index or if a DROP PRIMARY KEY statement - // was processed before this statement. If a DROP PRIMARY KEY - // statement was processed, then n.tableDesc.HasPrimaryKey() = false. - if n.tableDesc.HasPrimaryKey() && !n.tableDesc.IsPrimaryIndexDefaultRowID() { - return pgerror.Newf(pgcode.InvalidTableDefinition, - "multiple primary keys for table %q are not allowed", n.tableDesc.Name) - } - // Translate this operation into an ALTER PRIMARY KEY command. alterPK := &tree.AlterTableAlterPrimaryKey{ Columns: d.Columns, @@ -276,11 +272,6 @@ func (n *alterTableNode) startExec(params runParams) error { return err } } - // If the index is named, ensure that the name is unique. - // Unnamed indexes will be given a unique auto-generated name later on. - if d.Name != "" && n.tableDesc.ValidateIndexNameIsUnique(d.Name.String()) != nil { - return pgerror.Newf(pgcode.DuplicateRelation, "duplicate index name: %q", d.Name) - } idx := descpb.IndexDescriptor{ Name: string(d.Name), Unique: true, @@ -1559,6 +1550,82 @@ func (p *planner) removeColumnComment( return err } +// validateConstraintNameIsNotUsed checks that the name of the constraint we're +// trying to add isn't already used, and, if it is, whether the constraint +// addition should be skipped: +// - if the name is free to use, it returns false; +// - if it's already used but IF NOT EXISTS was specified, it returns true; +// - otherwise, it returns an error. +func validateConstraintNameIsNotUsed( + tableDesc *tabledesc.Mutable, cmd *tree.AlterTableAddConstraint, +) (skipAddConstraint bool, _ error) { + var name tree.Name + var hasIfNotExists bool + switch d := cmd.ConstraintDef.(type) { + case *tree.CheckConstraintTableDef: + name = d.Name + hasIfNotExists = d.IfNotExists + case *tree.ForeignKeyConstraintTableDef: + name = d.Name + hasIfNotExists = d.IfNotExists + case *tree.UniqueConstraintTableDef: + name = d.Name + hasIfNotExists = d.IfNotExists + if d.WithoutIndex { + break + } + // Handle edge cases specific to unique constraints with indexes. + if d.PrimaryKey { + // We only support "adding" a primary key when we are using the + // default rowid primary index or if a DROP PRIMARY KEY statement + // was processed before this statement. If a DROP PRIMARY KEY + // statement was processed, then n.tableDesc.HasPrimaryKey() = false. + if tableDesc.HasPrimaryKey() && !tableDesc.IsPrimaryIndexDefaultRowID() { + if d.IfNotExists { + return true, nil + } + return false, pgerror.Newf(pgcode.InvalidTableDefinition, + "multiple primary keys for table %q are not allowed", tableDesc.Name) + } + } + if name == "" { + return false, nil + } + idx, _ := tableDesc.FindIndexWithName(name.String()) + if idx == nil { + return false, nil + } + if d.IfNotExists { + return true, nil + } + if idx.Dropped() { + return false, pgerror.Newf(pgcode.DuplicateObject, "constraint with name %q already exists and is being dropped, try again later", name) + } + return false, pgerror.Newf(pgcode.DuplicateObject, "constraint with name %q already exists", name) + + default: + return false, errors.AssertionFailedf( + "unsupported constraint: %T", cmd.ConstraintDef) + } + + if name == "" { + return false, nil + } + info, err := tableDesc.GetConstraintInfo() + if err != nil { + // Unexpected error: table descriptor should be valid at this point. + return false, errors.WithAssertionFailure(err) + } + if _, isInUse := info[name.String()]; !isInUse { + return false, nil + } + if hasIfNotExists { + return true, nil + } + return false, pgerror.Newf(pgcode.DuplicateObject, + "duplicate constraint name: %q", name) +} + // updateFKBackReferenceName updates the name of a foreign key reference on // the referenced table descriptor. // TODO (lucy): This method is meant to be analogous to removeFKBackReference, diff --git a/pkg/sql/catalog/tabledesc/BUILD.bazel b/pkg/sql/catalog/tabledesc/BUILD.bazel index f16e0d02c5e5..23a830c69dc8 100644 --- a/pkg/sql/catalog/tabledesc/BUILD.bazel +++ b/pkg/sql/catalog/tabledesc/BUILD.bazel @@ -36,7 +36,6 @@ go_library( "//pkg/sql/privilege", "//pkg/sql/rowenc", "//pkg/sql/sem/tree", - "//pkg/sql/sqlerrors", "//pkg/sql/types", "//pkg/util", "//pkg/util/errorutil/unimplemented", diff --git a/pkg/sql/catalog/tabledesc/structured.go b/pkg/sql/catalog/tabledesc/structured.go index 79854c3347a9..3a4edf335301 100644 --- a/pkg/sql/catalog/tabledesc/structured.go +++ b/pkg/sql/catalog/tabledesc/structured.go @@ -29,7 +29,6 @@ import ( "github.com/cockroachdb/cockroach/pkg/sql/pgwire/pgerror" "github.com/cockroachdb/cockroach/pkg/sql/rowenc" "github.com/cockroachdb/cockroach/pkg/sql/sem/tree" - "github.com/cockroachdb/cockroach/pkg/sql/sqlerrors" "github.com/cockroachdb/cockroach/pkg/sql/types" "github.com/cockroachdb/cockroach/pkg/util/errorutil/unimplemented" "github.com/cockroachdb/cockroach/pkg/util/hlc" @@ -987,16 +986,6 @@ func (desc *Mutable) OriginalVersion() descpb.DescriptorVersion { return desc.ClusterVersion.Version } -// ValidateIndexNameIsUnique validates that the index name does not exist. -func (desc *wrapper) ValidateIndexNameIsUnique(indexName string) error { - if catalog.FindNonDropIndex(desc, func(idx catalog.Index) bool { - return idx.GetName() == indexName - }) != nil { - return sqlerrors.NewRelationAlreadyExistsError(indexName) - } - return nil -} - // FamilyHeuristicTargetBytes is the target total byte size of columns that the // current heuristic will assign to a family. const FamilyHeuristicTargetBytes = 256 diff --git a/pkg/sql/create_index.go b/pkg/sql/create_index.go index 11240f1922e8..0e5853790f94 100644 --- a/pkg/sql/create_index.go +++ b/pkg/sql/create_index.go @@ -189,9 +189,13 @@ func MakeIndexDescriptor( } // Ensure that the index name does not exist before trying to create the index. - if err := tableDesc.ValidateIndexNameIsUnique(string(n.Name)); err != nil { - return nil, err + if idx, _ := tableDesc.FindIndexWithName(n.Name.String()); idx != nil { + if idx.Dropped() { + return nil, pgerror.Newf(pgcode.DuplicateRelation, "index with name %q already exists and is being dropped, try again later", n.Name) + } + return nil, pgerror.Newf(pgcode.DuplicateRelation, "index with name %q already exists", n.Name) } + indexDesc := descpb.IndexDescriptor{ Name: string(n.Name), Unique: n.Unique, diff --git a/pkg/sql/create_table.go b/pkg/sql/create_table.go index 137a8306ee3c..5a691d53e7ca 100644 --- a/pkg/sql/create_table.go +++ b/pkg/sql/create_table.go @@ -1659,8 +1659,10 @@ func NewTableDesc( // If the index is named, ensure that the name is unique. Unnamed // indexes will be given a unique auto-generated name later on when // AllocateIDs is called. - if d.Name != "" && desc.ValidateIndexNameIsUnique(d.Name.String()) != nil { - return nil, pgerror.Newf(pgcode.DuplicateRelation, "duplicate index name: %q", d.Name) + if d.Name != "" { + if idx, _ := desc.FindIndexWithName(d.Name.String()); idx != nil { + return nil, pgerror.Newf(pgcode.DuplicateRelation, "duplicate index name: %q", d.Name) + } } if err := validateColumnsAreAccessible(&desc, d.Columns); err != nil { return nil, err @@ -1777,8 +1779,10 @@ func NewTableDesc( // If the index is named, ensure that the name is unique. Unnamed // indexes will be given a unique auto-generated name later on when // AllocateIDs is called. - if d.Name != "" && desc.ValidateIndexNameIsUnique(d.Name.String()) != nil { - return nil, pgerror.Newf(pgcode.DuplicateRelation, "duplicate index name: %q", d.Name) + if d.Name != "" { + if idx, _ := desc.FindIndexWithName(d.Name.String()); idx != nil { + return nil, pgerror.Newf(pgcode.DuplicateRelation, "duplicate index name: %q", d.Name) + } } if err := validateColumnsAreAccessible(&desc, d.Columns); err != nil { return nil, err diff --git a/pkg/sql/descriptor_mutation_test.go b/pkg/sql/descriptor_mutation_test.go index 8638125374c7..ca9cda13efbb 100644 --- a/pkg/sql/descriptor_mutation_test.go +++ b/pkg/sql/descriptor_mutation_test.go @@ -912,7 +912,7 @@ CREATE TABLE t.test (a STRING PRIMARY KEY, b STRING, c STRING, INDEX foo (c)); // "foo" is being added. mt.writeIndexMutation(ctx, "foo", descpb.DescriptorMutation{Direction: descpb.DescriptorMutation_ADD}) if _, err := sqlDB.Exec(`CREATE INDEX foo ON t.test (c)`); !testutils.IsError(err, - `relation "foo" already exists`) { + `index with name "foo" already exists`) { t.Fatal(err) } // Make "foo" live. @@ -974,7 +974,8 @@ CREATE TABLE t.test (a STRING PRIMARY KEY, b STRING, c STRING, INDEX foo (c)); // Add index DROP mutation "foo"" mt.writeIndexMutation(ctx, "foo", descpb.DescriptorMutation{Direction: descpb.DescriptorMutation_DROP}) - if _, err := sqlDB.Exec(`ALTER TABLE t.test ADD CONSTRAINT foo UNIQUE (c)`); !testutils.IsError(err, `index "foo" being dropped, try again later`) { + if _, err := sqlDB.Exec(`ALTER TABLE t.test ADD CONSTRAINT foo UNIQUE (c)`); !testutils.IsError(err, + `constraint with name "foo" already exists`) { t.Fatal(err) } // Make "foo" live. @@ -982,7 +983,7 @@ CREATE TABLE t.test (a STRING PRIMARY KEY, b STRING, c STRING, INDEX foo (c)); // "foo" is being added. mt.writeIndexMutation(ctx, "foo", descpb.DescriptorMutation{Direction: descpb.DescriptorMutation_ADD}) if _, err := sqlDB.Exec(`ALTER TABLE t.test ADD CONSTRAINT foo UNIQUE (c)`); !testutils.IsError(err, - `duplicate index name: "foo"`) { + `constraint with name "foo" already exists`) { t.Fatal(err) } // Make "foo" live. diff --git a/pkg/sql/logictest/testdata/logic_test/alter_primary_key b/pkg/sql/logictest/testdata/logic_test/alter_primary_key index e7923e6002b3..ef1d47e617fb 100644 --- a/pkg/sql/logictest/testdata/logic_test/alter_primary_key +++ b/pkg/sql/logictest/testdata/logic_test/alter_primary_key @@ -578,7 +578,7 @@ t CREATE TABLE public.t ( statement ok CREATE INDEX i ON t (x); -statement error pq: constraint with name i already exists +statement error pgcode 42710 constraint with name \"i\" already exists ALTER TABLE t DROP CONSTRAINT "my_pk", ADD CONSTRAINT "i" PRIMARY KEY (x); # Regression for #45362. @@ -622,25 +622,31 @@ statement error pq: relation "t" \([0-9]+\): unimplemented: primary key dropped ALTER TABLE t DROP CONSTRAINT "t_pkey" statement error pq: multiple primary keys for table "t" are not allowed -ALTER TABLE t ADD CONSTRAINT "t_pkey" PRIMARY KEY (y), DROP CONSTRAINT "primary" +ALTER TABLE t ADD CONSTRAINT "t_pkey" PRIMARY KEY (y), DROP CONSTRAINT "t_pkey" statement error pq: multiple primary keys for table "t" are not allowed ALTER TABLE t ADD CONSTRAINT "t_pkey" PRIMARY KEY (y) -statement ok +statement error pgcode 42710 constraint with name \"t_pkey\" already exists ALTER TABLE t DROP CONSTRAINT "t_pkey", ADD CONSTRAINT "t_pkey" PRIMARY KEY (y) +statement ok +ALTER TABLE t DROP CONSTRAINT "t_pkey", ADD CONSTRAINT "t_pkey_v2" PRIMARY KEY (y) + query TT SHOW CREATE t ---- t CREATE TABLE public.t ( x INT8 NOT NULL, y INT8 NOT NULL, - CONSTRAINT t_pkey PRIMARY KEY (y ASC), + CONSTRAINT t_pkey_v2 PRIMARY KEY (y ASC), FAMILY fam_0_x (x), FAMILY fam_1_y (y) ) +statement ok +ALTER TABLE t ADD CONSTRAINT IF NOT EXISTS "t_pkey" PRIMARY KEY (x) + # Test that we can issue a DROP CONSTRAINT + ADD PRIMARY KEY # in the same transaction. statement ok @@ -653,9 +659,23 @@ BEGIN statement ok ALTER TABLE t DROP CONSTRAINT "t_pkey" -statement ok +statement error pgcode 42710 constraint with name \"t_pkey\" already exists ALTER TABLE t ADD CONSTRAINT "t_pkey" PRIMARY KEY (y) +statement ok +ROLLBACK; +DROP TABLE t; +CREATE TABLE t (x INT PRIMARY KEY, y INT NOT NULL, FAMILY (x), FAMILY (y)) + +statement ok +BEGIN + +statement ok +ALTER TABLE t DROP CONSTRAINT "t_pkey" + +statement ok +ALTER TABLE t ADD CONSTRAINT "t_pkey_v2" PRIMARY KEY (y) + statement ok COMMIT @@ -665,7 +685,7 @@ SHOW CREATE t t CREATE TABLE public.t ( x INT8 NOT NULL, y INT8 NOT NULL, - CONSTRAINT t_pkey PRIMARY KEY (y ASC), + CONSTRAINT t_pkey_v2 PRIMARY KEY (y ASC), FAMILY fam_0_x (x), FAMILY fam_1_y (y) ) diff --git a/pkg/sql/logictest/testdata/logic_test/alter_table b/pkg/sql/logictest/testdata/logic_test/alter_table index c58ad580f73e..873545e1c323 100644 --- a/pkg/sql/logictest/testdata/logic_test/alter_table +++ b/pkg/sql/logictest/testdata/logic_test/alter_table @@ -28,6 +28,12 @@ b INT8 true NULL · {t_ statement ok ALTER TABLE t ADD CONSTRAINT foo UNIQUE (b) +statement ok +ALTER TABLE t ADD CONSTRAINT IF NOT EXISTS foo UNIQUE (b) + +statement ok +ALTER TABLE t ADD CONSTRAINT IF NOT EXISTS foo UNIQUE (f) + query TTTTRT SELECT job_type, description, user_name, status, fraction_completed, error FROM crdb_internal.jobs @@ -37,7 +43,7 @@ LIMIT 1 ---- SCHEMA CHANGE ALTER TABLE test.public.t ADD CONSTRAINT foo UNIQUE (b) root succeeded 1 · -statement error pgcode 42P07 duplicate index name: "foo" +statement error pgcode 42710 constraint with name \"foo\" already exists ALTER TABLE t ADD CONSTRAINT foo UNIQUE (b) statement error pq: multiple primary keys for table "t" are not allowed @@ -116,7 +122,7 @@ statement ok DELETE FROM t WHERE a = -2 statement ok -ALTER TABLE t ADD CONSTRAINT check_a CHECK (a > 0) +ALTER TABLE t ADD CONSTRAINT IF NOT EXISTS check_a CHECK (a > 0) statement error CHECK INSERT INTO t (a) VALUES (-3) @@ -132,9 +138,20 @@ t t_pkey PRIMARY KEY PRIMARY KEY (a ASC) true statement error duplicate constraint name ALTER TABLE t ADD CONSTRAINT check_a CHECK (a > 0) +statement ok +ALTER TABLE t ADD CONSTRAINT IF NOT EXISTS check_a CHECK (a < 0) + statement error duplicate constraint name ALTER TABLE t ADD CONSTRAINT t_f_fkey FOREIGN KEY (a) REFERENCES other (b) +# Should be a no-op. +statement ok +ALTER TABLE t ADD CONSTRAINT IF NOT EXISTS t_f_fkey FOREIGN KEY (a) REFERENCES other (b) + +# Should be a no-op. +statement ok +ALTER TABLE t ADD CONSTRAINT IF NOT EXISTS t_f_fkey CHECK (a < 0) + # added constraints with generated names avoid name collisions. statement ok ALTER TABLE t ADD CHECK (a > 0) @@ -1821,7 +1838,7 @@ subtest unique_index_duplicate_name statement ok CREATE TABLE duplicate_index_test (k INT PRIMARY KEY, v INT, INDEX idx (v)); -statement error pgcode 42P07 duplicate index name: \"idx\" +statement error pgcode 42710 constraint with name \"idx\" already exists ALTER TABLE duplicate_index_test ADD CONSTRAINT idx UNIQUE (v) # Regression test for a bug which occurred when adding a foreign key diff --git a/pkg/sql/logictest/testdata/logic_test/create_index b/pkg/sql/logictest/testdata/logic_test/create_index index 22b8a05b0e65..47c67338888a 100644 --- a/pkg/sql/logictest/testdata/logic_test/create_index +++ b/pkg/sql/logictest/testdata/logic_test/create_index @@ -14,7 +14,7 @@ user root statement ok CREATE INDEX foo ON t (b) -statement error relation \"foo\" already exists +statement error pgcode 42P07 index with name \"foo\" already exists CREATE INDEX foo ON t (a) statement error column "c" does not exist diff --git a/pkg/sql/opt/exec/execbuilder/testdata/ddl b/pkg/sql/opt/exec/execbuilder/testdata/ddl index 7bc4b22de6e7..7e9511cc8324 100644 --- a/pkg/sql/opt/exec/execbuilder/testdata/ddl +++ b/pkg/sql/opt/exec/execbuilder/testdata/ddl @@ -144,7 +144,7 @@ user root statement ok CREATE INDEX foo ON t (b) -statement error relation \"foo\" already exists +statement error index with name \"foo\" already exists CREATE INDEX foo ON t (a) statement error column "c" does not exist diff --git a/pkg/sql/parser/sql.y b/pkg/sql/parser/sql.y index 3215dc3faff1..57b11dec93ce 100644 --- a/pkg/sql/parser/sql.y +++ b/pkg/sql/parser/sql.y @@ -2218,6 +2218,17 @@ alter_table_cmd: ValidationBehavior: $3.validationBehavior(), } } + // ALTER TABLE ADD CONSTRAINT IF NOT EXISTS ... +| ADD CONSTRAINT IF NOT EXISTS constraint_name constraint_elem opt_validate_behavior + { + def := $7.constraintDef() + def.SetName(tree.Name($6)) + def.SetIfNotExists() + $$.val = &tree.AlterTableAddConstraint{ + ConstraintDef: def, + ValidationBehavior: $8.validationBehavior(), + } + } // ALTER TABLE ALTER CONSTRAINT ... | ALTER CONSTRAINT constraint_name error { return unimplementedWithIssueDetail(sqllex, 31632, "alter constraint") } // ALTER TABLE INHERITS .... diff --git a/pkg/sql/sem/tree/create.go b/pkg/sql/sem/tree/create.go index 4bff09dcf945..8ab7a24e9ff0 100644 --- a/pkg/sql/sem/tree/create.go +++ b/pkg/sql/sem/tree/create.go @@ -984,6 +984,10 @@ type ConstraintTableDef interface { // SetName replaces the name of the definition in-place. Used in the parser. SetName(name Name) + + // SetIfNotExists sets this definition as coming from an + // ADD CONSTRAINT IF NOT EXISTS statement. Used in the parser. + SetIfNotExists() } func (*UniqueConstraintTableDef) constraintTableDef() {} @@ -996,6 +1000,7 @@ type UniqueConstraintTableDef struct { IndexTableDef PrimaryKey bool WithoutIndex bool + IfNotExists bool } // SetName implements the TableDef interface. @@ -1003,10 +1008,18 @@ func (node *UniqueConstraintTableDef) SetName(name Name) { node.Name = name } +// SetIfNotExists implements the ConstraintTableDef interface. +func (node *UniqueConstraintTableDef) SetIfNotExists() { + node.IfNotExists = true +} + // Format implements the NodeFormatter interface. func (node *UniqueConstraintTableDef) Format(ctx *FmtCtx) { if node.Name != "" { ctx.WriteString("CONSTRAINT ") + if node.IfNotExists { + ctx.WriteString("IF NOT EXISTS ") + } ctx.FormatNode(&node.Name) ctx.WriteByte(' ') } @@ -1107,18 +1120,22 @@ func (c CompositeKeyMatchMethod) String() string { // ForeignKeyConstraintTableDef represents a FOREIGN KEY constraint in the AST. type ForeignKeyConstraintTableDef struct { - Name Name - Table TableName - FromCols NameList - ToCols NameList - Actions ReferenceActions - Match CompositeKeyMatchMethod + Name Name + Table TableName + FromCols NameList + ToCols NameList + Actions ReferenceActions + Match CompositeKeyMatchMethod + IfNotExists bool } // Format implements the NodeFormatter interface. func (node *ForeignKeyConstraintTableDef) Format(ctx *FmtCtx) { if node.Name != "" { ctx.WriteString("CONSTRAINT ") + if node.IfNotExists { + ctx.WriteString("IF NOT EXISTS ") + } ctx.FormatNode(&node.Name) ctx.WriteByte(' ') } @@ -1147,12 +1164,18 @@ func (node *ForeignKeyConstraintTableDef) SetName(name Name) { node.Name = name } +// SetIfNotExists implements the ConstraintTableDef interface. +func (node *ForeignKeyConstraintTableDef) SetIfNotExists() { + node.IfNotExists = true +} + // CheckConstraintTableDef represents a check constraint within a CREATE // TABLE statement. type CheckConstraintTableDef struct { - Name Name - Expr Expr - Hidden bool + Name Name + Expr Expr + Hidden bool + IfNotExists bool } // SetName implements the ConstraintTableDef interface. @@ -1160,10 +1183,18 @@ func (node *CheckConstraintTableDef) SetName(name Name) { node.Name = name } +// SetIfNotExists implements the ConstraintTableDef interface. +func (node *CheckConstraintTableDef) SetIfNotExists() { + node.IfNotExists = true +} + // Format implements the NodeFormatter interface. func (node *CheckConstraintTableDef) Format(ctx *FmtCtx) { if node.Name != "" { ctx.WriteString("CONSTRAINT ") + if node.IfNotExists { + ctx.WriteString("IF NOT EXISTS ") + } ctx.FormatNode(&node.Name) ctx.WriteByte(' ') }