From 387e4649e6a1e99fcdc2d0922d14ba0105f73359 Mon Sep 17 00:00:00 2001 From: Andrew Delph Date: Wed, 6 Dec 2023 11:40:05 -0500 Subject: [PATCH] sql: Allow Alter Column to ADD and SET Identity fixes: #110010 This change adds a new command, 'ALTER TABLE ALTER [COLUMN] ADD GENERATED { ALWAYS | BY DEFAULT } AS IDENTITY [( )]' and 'ALTER TABLE ALTER [COLUMN] SET GENERATED { ALWAYS | BY DEFAULT }', which allows a column to become an Identity or change the generation type of the the identity. Release note (sql change): Columns can be changed to an identity column by running one of: - `ALTER TABLE t ALTER COLUMN c ADD GENERATED ALWAYS AS IDENTITY [( )]` - `ALTER TABLE t ALTER COLUMN c ADD GENERATED BY DEFAULT AS IDENTITY[( )]` Identity columns can have their identity type altered by running one of: - `ALTER TABLE t ALTER COLUMN c SET GENERATED ALWAYS` - `ALTER TABLE t ALTER COLUMN c SET GENERATED BY DEFAULT` --- docs/generated/sql/bnf/alter_column.bnf | 24 +++ docs/generated/sql/bnf/alter_table_cmds.bnf | 2 +- .../sql/bnf/alter_table_partition_by.bnf | 4 +- docs/generated/sql/bnf/stmt_block.bnf | 24 ++- pkg/sql/alter_table.go | 123 +++++++++++++++ pkg/sql/importer/import_stmt_test.go | 8 - .../logictest/testdata/logic_test/alter_table | 142 ++++++++++++++++++ .../testdata/logic_test/information_schema | 64 ++++++++ pkg/sql/parser/sql.y | 40 +++++ pkg/sql/parser/testdata/alter_table | 48 ++++++ pkg/sql/sem/tree/alter_table.go | 68 +++++++++ pkg/sql/sem/tree/stmt.go | 1 + pkg/sql/sequence_test.go | 14 ++ 13 files changed, 545 insertions(+), 17 deletions(-) diff --git a/docs/generated/sql/bnf/alter_column.bnf b/docs/generated/sql/bnf/alter_column.bnf index dde4c1fd386e..9304124777b8 100644 --- a/docs/generated/sql/bnf/alter_column.bnf +++ b/docs/generated/sql/bnf/alter_column.bnf @@ -9,6 +9,18 @@ alter_onetable_stmt ::= | 'ALTER' 'TABLE' table_name 'ALTER' column_name 'SET' ('NOT' | ) 'VISIBLE' | 'ALTER' 'TABLE' table_name 'ALTER' 'COLUMN' column_name 'DROP' 'NOT' 'NULL' | 'ALTER' 'TABLE' table_name 'ALTER' column_name 'DROP' 'NOT' 'NULL' + | 'ALTER' 'TABLE' table_name 'ALTER' 'COLUMN' column_name 'ADD' generated_always_as 'IDENTITY' + | 'ALTER' 'TABLE' table_name 'ALTER' column_name 'ADD' generated_always_as 'IDENTITY' + | 'ALTER' 'TABLE' table_name 'ALTER' 'COLUMN' column_name 'ADD' generated_by_default_as 'IDENTITY' + | 'ALTER' 'TABLE' table_name 'ALTER' column_name 'ADD' generated_by_default_as 'IDENTITY' + | 'ALTER' 'TABLE' table_name 'ALTER' 'COLUMN' column_name 'ADD' generated_always_as 'IDENTITY' '(' opt_sequence_option_list ')' + | 'ALTER' 'TABLE' table_name 'ALTER' column_name 'ADD' generated_always_as 'IDENTITY' '(' opt_sequence_option_list ')' + | 'ALTER' 'TABLE' table_name 'ALTER' 'COLUMN' column_name 'ADD' generated_by_default_as 'IDENTITY' '(' opt_sequence_option_list ')' + | 'ALTER' 'TABLE' table_name 'ALTER' column_name 'ADD' generated_by_default_as 'IDENTITY' '(' opt_sequence_option_list ')' + | 'ALTER' 'TABLE' table_name 'ALTER' 'COLUMN' column_name set_generated_always + | 'ALTER' 'TABLE' table_name 'ALTER' column_name set_generated_always + | 'ALTER' 'TABLE' table_name 'ALTER' 'COLUMN' column_name set_generated_default + | 'ALTER' 'TABLE' table_name 'ALTER' column_name set_generated_default | 'ALTER' 'TABLE' table_name 'ALTER' 'COLUMN' column_name 'DROP' 'STORED' | 'ALTER' 'TABLE' table_name 'ALTER' column_name 'DROP' 'STORED' | 'ALTER' 'TABLE' table_name 'ALTER' 'COLUMN' column_name 'SET' 'NOT' 'NULL' @@ -39,6 +51,18 @@ alter_onetable_stmt ::= | 'ALTER' 'TABLE' 'IF' 'EXISTS' table_name 'ALTER' column_name 'SET' ('NOT' | ) 'VISIBLE' | 'ALTER' 'TABLE' 'IF' 'EXISTS' table_name 'ALTER' 'COLUMN' column_name 'DROP' 'NOT' 'NULL' | 'ALTER' 'TABLE' 'IF' 'EXISTS' table_name 'ALTER' column_name 'DROP' 'NOT' 'NULL' + | 'ALTER' 'TABLE' 'IF' 'EXISTS' table_name 'ALTER' 'COLUMN' column_name 'ADD' generated_always_as 'IDENTITY' + | 'ALTER' 'TABLE' 'IF' 'EXISTS' table_name 'ALTER' column_name 'ADD' generated_always_as 'IDENTITY' + | 'ALTER' 'TABLE' 'IF' 'EXISTS' table_name 'ALTER' 'COLUMN' column_name 'ADD' generated_by_default_as 'IDENTITY' + | 'ALTER' 'TABLE' 'IF' 'EXISTS' table_name 'ALTER' column_name 'ADD' generated_by_default_as 'IDENTITY' + | 'ALTER' 'TABLE' 'IF' 'EXISTS' table_name 'ALTER' 'COLUMN' column_name 'ADD' generated_always_as 'IDENTITY' '(' opt_sequence_option_list ')' + | 'ALTER' 'TABLE' 'IF' 'EXISTS' table_name 'ALTER' column_name 'ADD' generated_always_as 'IDENTITY' '(' opt_sequence_option_list ')' + | 'ALTER' 'TABLE' 'IF' 'EXISTS' table_name 'ALTER' 'COLUMN' column_name 'ADD' generated_by_default_as 'IDENTITY' '(' opt_sequence_option_list ')' + | 'ALTER' 'TABLE' 'IF' 'EXISTS' table_name 'ALTER' column_name 'ADD' generated_by_default_as 'IDENTITY' '(' opt_sequence_option_list ')' + | 'ALTER' 'TABLE' 'IF' 'EXISTS' table_name 'ALTER' 'COLUMN' column_name set_generated_always + | 'ALTER' 'TABLE' 'IF' 'EXISTS' table_name 'ALTER' column_name set_generated_always + | 'ALTER' 'TABLE' 'IF' 'EXISTS' table_name 'ALTER' 'COLUMN' column_name set_generated_default + | 'ALTER' 'TABLE' 'IF' 'EXISTS' table_name 'ALTER' column_name set_generated_default | 'ALTER' 'TABLE' 'IF' 'EXISTS' table_name 'ALTER' 'COLUMN' column_name 'DROP' 'STORED' | 'ALTER' 'TABLE' 'IF' 'EXISTS' table_name 'ALTER' column_name 'DROP' 'STORED' | 'ALTER' 'TABLE' 'IF' 'EXISTS' table_name 'ALTER' 'COLUMN' column_name 'SET' 'NOT' 'NULL' diff --git a/docs/generated/sql/bnf/alter_table_cmds.bnf b/docs/generated/sql/bnf/alter_table_cmds.bnf index de8b98273d4c..548a62961a1d 100644 --- a/docs/generated/sql/bnf/alter_table_cmds.bnf +++ b/docs/generated/sql/bnf/alter_table_cmds.bnf @@ -1,2 +1,2 @@ alter_table_cmds ::= - ( ( 'RENAME' ( 'COLUMN' | ) column_name 'TO' column_new_name | 'RENAME' 'CONSTRAINT' constraint_name 'TO' constraint_new_name | 'ADD' ( column_name typename ( ( ) ( ( col_qualification ) )* ) ) | 'ADD' 'IF' 'NOT' 'EXISTS' ( column_name typename ( ( ) ( ( col_qualification ) )* ) ) | 'ADD' 'COLUMN' ( column_name typename ( ( ) ( ( col_qualification ) )* ) ) | 'ADD' 'COLUMN' 'IF' 'NOT' 'EXISTS' ( column_name typename ( ( ) ( ( col_qualification ) )* ) ) | 'ALTER' ( 'COLUMN' | ) column_name ( 'SET' 'DEFAULT' a_expr | 'DROP' 'DEFAULT' ) | 'ALTER' ( 'COLUMN' | ) column_name ( 'SET' 'ON' 'UPDATE' a_expr | 'DROP' 'ON' 'UPDATE' ) | 'ALTER' ( 'COLUMN' | ) column_name ( 'SET' 'VISIBLE' | 'SET' 'NOT' '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 ) ( 'NOT' 'VALID' | ) | 'ADD' 'CONSTRAINT' 'IF' 'NOT' 'EXISTS' constraint_name constraint_elem ( 'NOT' 'VALID' | ) | 'ALTER' 'PRIMARY' 'KEY' 'USING' 'COLUMNS' '(' index_params ')' ( 'USING' 'HASH' | ) ( 'WITH' '(' ( ( ( storage_parameter_key '=' value ) ) ( ( ',' ( storage_parameter_key '=' value ) ) )* ) ')' ) | 'VALIDATE' 'CONSTRAINT' constraint_name | 'DROP' 'CONSTRAINT' 'IF' 'EXISTS' constraint_name ( 'CASCADE' | 'RESTRICT' | ) | 'DROP' 'CONSTRAINT' constraint_name ( 'CASCADE' | 'RESTRICT' | ) | 'EXPERIMENTAL_AUDIT' 'SET' ( 'READ' 'WRITE' | 'OFF' ) | ( ( 'PARTITION' 'BY' ( 'LIST' '(' name_list ')' '(' list_partitions ')' | 'RANGE' '(' name_list ')' '(' range_partitions ')' | 'NOTHING' ) ) | 'PARTITION' 'ALL' 'BY' ( 'LIST' '(' name_list ')' '(' list_partitions ')' | 'RANGE' '(' name_list ')' '(' range_partitions ')' | 'NOTHING' ) ) | 'SET' '(' ( ( ( storage_parameter_key '=' value ) ) ( ( ',' ( storage_parameter_key '=' value ) ) )* ) ')' | 'RESET' '(' ( ( storage_parameter_key ) ( ( ',' storage_parameter_key ) )* ) ')' ) ) ( ( ',' ( 'RENAME' ( 'COLUMN' | ) column_name 'TO' column_new_name | 'RENAME' 'CONSTRAINT' constraint_name 'TO' constraint_new_name | 'ADD' ( column_name typename ( ( ) ( ( col_qualification ) )* ) ) | 'ADD' 'IF' 'NOT' 'EXISTS' ( column_name typename ( ( ) ( ( col_qualification ) )* ) ) | 'ADD' 'COLUMN' ( column_name typename ( ( ) ( ( col_qualification ) )* ) ) | 'ADD' 'COLUMN' 'IF' 'NOT' 'EXISTS' ( column_name typename ( ( ) ( ( col_qualification ) )* ) ) | 'ALTER' ( 'COLUMN' | ) column_name ( 'SET' 'DEFAULT' a_expr | 'DROP' 'DEFAULT' ) | 'ALTER' ( 'COLUMN' | ) column_name ( 'SET' 'ON' 'UPDATE' a_expr | 'DROP' 'ON' 'UPDATE' ) | 'ALTER' ( 'COLUMN' | ) column_name ( 'SET' 'VISIBLE' | 'SET' 'NOT' '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 ) ( 'NOT' 'VALID' | ) | 'ADD' 'CONSTRAINT' 'IF' 'NOT' 'EXISTS' constraint_name constraint_elem ( 'NOT' 'VALID' | ) | 'ALTER' 'PRIMARY' 'KEY' 'USING' 'COLUMNS' '(' index_params ')' ( 'USING' 'HASH' | ) ( 'WITH' '(' ( ( ( storage_parameter_key '=' value ) ) ( ( ',' ( storage_parameter_key '=' value ) ) )* ) ')' ) | 'VALIDATE' 'CONSTRAINT' constraint_name | 'DROP' 'CONSTRAINT' 'IF' 'EXISTS' constraint_name ( 'CASCADE' | 'RESTRICT' | ) | 'DROP' 'CONSTRAINT' constraint_name ( 'CASCADE' | 'RESTRICT' | ) | 'EXPERIMENTAL_AUDIT' 'SET' ( 'READ' 'WRITE' | 'OFF' ) | ( ( 'PARTITION' 'BY' ( 'LIST' '(' name_list ')' '(' list_partitions ')' | 'RANGE' '(' name_list ')' '(' range_partitions ')' | 'NOTHING' ) ) | 'PARTITION' 'ALL' 'BY' ( 'LIST' '(' name_list ')' '(' list_partitions ')' | 'RANGE' '(' name_list ')' '(' range_partitions ')' | 'NOTHING' ) ) | 'SET' '(' ( ( ( storage_parameter_key '=' value ) ) ( ( ',' ( storage_parameter_key '=' value ) ) )* ) ')' | 'RESET' '(' ( ( storage_parameter_key ) ( ( ',' storage_parameter_key ) )* ) ')' ) ) )* + ( ( 'RENAME' ( 'COLUMN' | ) column_name 'TO' column_new_name | 'RENAME' 'CONSTRAINT' constraint_name 'TO' constraint_new_name | 'ADD' ( column_name typename ( ( ) ( ( col_qualification ) )* ) ) | 'ADD' 'IF' 'NOT' 'EXISTS' ( column_name typename ( ( ) ( ( col_qualification ) )* ) ) | 'ADD' 'COLUMN' ( column_name typename ( ( ) ( ( col_qualification ) )* ) ) | 'ADD' 'COLUMN' 'IF' 'NOT' 'EXISTS' ( column_name typename ( ( ) ( ( col_qualification ) )* ) ) | 'ALTER' ( 'COLUMN' | ) column_name ( 'SET' 'DEFAULT' a_expr | 'DROP' 'DEFAULT' ) | 'ALTER' ( 'COLUMN' | ) column_name ( 'SET' 'ON' 'UPDATE' a_expr | 'DROP' 'ON' 'UPDATE' ) | 'ALTER' ( 'COLUMN' | ) column_name ( 'SET' 'VISIBLE' | 'SET' 'NOT' 'VISIBLE' ) | 'ALTER' ( 'COLUMN' | ) column_name 'DROP' 'NOT' 'NULL' | 'ALTER' ( 'COLUMN' | ) column_name 'ADD' generated_always_as 'IDENTITY' | 'ALTER' ( 'COLUMN' | ) column_name 'ADD' generated_by_default_as 'IDENTITY' | 'ALTER' ( 'COLUMN' | ) column_name 'ADD' generated_always_as 'IDENTITY' '(' opt_sequence_option_list ')' | 'ALTER' ( 'COLUMN' | ) column_name 'ADD' generated_by_default_as 'IDENTITY' '(' opt_sequence_option_list ')' | 'ALTER' ( 'COLUMN' | ) column_name set_generated_always | 'ALTER' ( 'COLUMN' | ) column_name set_generated_default | '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 ) ( 'NOT' 'VALID' | ) | 'ADD' 'CONSTRAINT' 'IF' 'NOT' 'EXISTS' constraint_name constraint_elem ( 'NOT' 'VALID' | ) | 'ALTER' 'PRIMARY' 'KEY' 'USING' 'COLUMNS' '(' index_params ')' ( 'USING' 'HASH' | ) ( 'WITH' '(' ( ( ( storage_parameter_key '=' value ) ) ( ( ',' ( storage_parameter_key '=' value ) ) )* ) ')' ) | 'VALIDATE' 'CONSTRAINT' constraint_name | 'DROP' 'CONSTRAINT' 'IF' 'EXISTS' constraint_name ( 'CASCADE' | 'RESTRICT' | ) | 'DROP' 'CONSTRAINT' constraint_name ( 'CASCADE' | 'RESTRICT' | ) | 'EXPERIMENTAL_AUDIT' 'SET' ( 'READ' 'WRITE' | 'OFF' ) | ( ( 'PARTITION' 'BY' ( 'LIST' '(' name_list ')' '(' list_partitions ')' | 'RANGE' '(' name_list ')' '(' range_partitions ')' | 'NOTHING' ) ) | 'PARTITION' 'ALL' 'BY' ( 'LIST' '(' name_list ')' '(' list_partitions ')' | 'RANGE' '(' name_list ')' '(' range_partitions ')' | 'NOTHING' ) ) | 'SET' '(' ( ( ( storage_parameter_key '=' value ) ) ( ( ',' ( storage_parameter_key '=' value ) ) )* ) ')' | 'RESET' '(' ( ( storage_parameter_key ) ( ( ',' storage_parameter_key ) )* ) ')' ) ) ( ( ',' ( 'RENAME' ( 'COLUMN' | ) column_name 'TO' column_new_name | 'RENAME' 'CONSTRAINT' constraint_name 'TO' constraint_new_name | 'ADD' ( column_name typename ( ( ) ( ( col_qualification ) )* ) ) | 'ADD' 'IF' 'NOT' 'EXISTS' ( column_name typename ( ( ) ( ( col_qualification ) )* ) ) | 'ADD' 'COLUMN' ( column_name typename ( ( ) ( ( col_qualification ) )* ) ) | 'ADD' 'COLUMN' 'IF' 'NOT' 'EXISTS' ( column_name typename ( ( ) ( ( col_qualification ) )* ) ) | 'ALTER' ( 'COLUMN' | ) column_name ( 'SET' 'DEFAULT' a_expr | 'DROP' 'DEFAULT' ) | 'ALTER' ( 'COLUMN' | ) column_name ( 'SET' 'ON' 'UPDATE' a_expr | 'DROP' 'ON' 'UPDATE' ) | 'ALTER' ( 'COLUMN' | ) column_name ( 'SET' 'VISIBLE' | 'SET' 'NOT' 'VISIBLE' ) | 'ALTER' ( 'COLUMN' | ) column_name 'DROP' 'NOT' 'NULL' | 'ALTER' ( 'COLUMN' | ) column_name 'ADD' generated_always_as 'IDENTITY' | 'ALTER' ( 'COLUMN' | ) column_name 'ADD' generated_by_default_as 'IDENTITY' | 'ALTER' ( 'COLUMN' | ) column_name 'ADD' generated_always_as 'IDENTITY' '(' opt_sequence_option_list ')' | 'ALTER' ( 'COLUMN' | ) column_name 'ADD' generated_by_default_as 'IDENTITY' '(' opt_sequence_option_list ')' | 'ALTER' ( 'COLUMN' | ) column_name set_generated_always | 'ALTER' ( 'COLUMN' | ) column_name set_generated_default | '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 ) ( 'NOT' 'VALID' | ) | 'ADD' 'CONSTRAINT' 'IF' 'NOT' 'EXISTS' constraint_name constraint_elem ( 'NOT' 'VALID' | ) | 'ALTER' 'PRIMARY' 'KEY' 'USING' 'COLUMNS' '(' index_params ')' ( 'USING' 'HASH' | ) ( 'WITH' '(' ( ( ( storage_parameter_key '=' value ) ) ( ( ',' ( storage_parameter_key '=' value ) ) )* ) ')' ) | 'VALIDATE' 'CONSTRAINT' constraint_name | 'DROP' 'CONSTRAINT' 'IF' 'EXISTS' constraint_name ( 'CASCADE' | 'RESTRICT' | ) | 'DROP' 'CONSTRAINT' constraint_name ( 'CASCADE' | 'RESTRICT' | ) | 'EXPERIMENTAL_AUDIT' 'SET' ( 'READ' 'WRITE' | 'OFF' ) | ( ( 'PARTITION' 'BY' ( 'LIST' '(' name_list ')' '(' list_partitions ')' | 'RANGE' '(' name_list ')' '(' range_partitions ')' | 'NOTHING' ) ) | 'PARTITION' 'ALL' 'BY' ( 'LIST' '(' name_list ')' '(' list_partitions ')' | 'RANGE' '(' name_list ')' '(' range_partitions ')' | 'NOTHING' ) ) | 'SET' '(' ( ( ( storage_parameter_key '=' value ) ) ( ( ',' ( storage_parameter_key '=' value ) ) )* ) ')' | 'RESET' '(' ( ( storage_parameter_key ) ( ( ',' storage_parameter_key ) )* ) ')' ) ) )* diff --git a/docs/generated/sql/bnf/alter_table_partition_by.bnf b/docs/generated/sql/bnf/alter_table_partition_by.bnf index a828c0ce3a27..df89b7e3ffc1 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_table_def | 'ADD' 'IF' 'NOT' 'EXISTS' column_table_def | 'ADD' 'COLUMN' column_table_def | 'ADD' 'COLUMN' 'IF' 'NOT' 'EXISTS' column_table_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 opt_with_storage_parameter_list | '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_by_inner | 'PARTITION' 'ALL' 'BY' partition_by_inner ) | 'SET' '(' storage_parameter_list ')' | 'RESET' '(' storage_parameter_key_list ')' ) ) )* - | '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_table_def | 'ADD' 'IF' 'NOT' 'EXISTS' column_table_def | 'ADD' 'COLUMN' column_table_def | 'ADD' 'COLUMN' 'IF' 'NOT' 'EXISTS' column_table_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 opt_with_storage_parameter_list | '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_by_inner | 'PARTITION' 'ALL' 'BY' partition_by_inner ) | 'SET' '(' storage_parameter_list ')' | 'RESET' '(' storage_parameter_key_list ')' ) ) )* + '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_table_def | 'ADD' 'IF' 'NOT' 'EXISTS' column_table_def | 'ADD' 'COLUMN' column_table_def | 'ADD' 'COLUMN' 'IF' 'NOT' 'EXISTS' column_table_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 'ADD' generated_always_as 'IDENTITY' | 'ALTER' opt_column column_name 'ADD' generated_by_default_as 'IDENTITY' | 'ALTER' opt_column column_name 'ADD' generated_always_as 'IDENTITY' '(' opt_sequence_option_list ')' | 'ALTER' opt_column column_name 'ADD' generated_by_default_as 'IDENTITY' '(' opt_sequence_option_list ')' | 'ALTER' opt_column column_name set_generated_always | 'ALTER' opt_column column_name set_generated_default | '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 opt_with_storage_parameter_list | '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_by_inner | 'PARTITION' 'ALL' 'BY' partition_by_inner ) | 'SET' '(' storage_parameter_list ')' | 'RESET' '(' storage_parameter_key_list ')' ) ) )* + | '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_table_def | 'ADD' 'IF' 'NOT' 'EXISTS' column_table_def | 'ADD' 'COLUMN' column_table_def | 'ADD' 'COLUMN' 'IF' 'NOT' 'EXISTS' column_table_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 'ADD' generated_always_as 'IDENTITY' | 'ALTER' opt_column column_name 'ADD' generated_by_default_as 'IDENTITY' | 'ALTER' opt_column column_name 'ADD' generated_always_as 'IDENTITY' '(' opt_sequence_option_list ')' | 'ALTER' opt_column column_name 'ADD' generated_by_default_as 'IDENTITY' '(' opt_sequence_option_list ')' | 'ALTER' opt_column column_name set_generated_always | 'ALTER' opt_column column_name set_generated_default | '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 opt_with_storage_parameter_list | '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_by_inner | 'PARTITION' 'ALL' 'BY' partition_by_inner ) | 'SET' '(' storage_parameter_list ')' | 'RESET' '(' storage_parameter_key_list ')' ) ) )* diff --git a/docs/generated/sql/bnf/stmt_block.bnf b/docs/generated/sql/bnf/stmt_block.bnf index 6b4b4b909196..706579c5bbfd 100644 --- a/docs/generated/sql/bnf/stmt_block.bnf +++ b/docs/generated/sql/bnf/stmt_block.bnf @@ -3420,6 +3420,12 @@ alter_table_cmd ::= | '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 'ADD' generated_always_as 'IDENTITY' + | 'ALTER' opt_column column_name 'ADD' generated_by_default_as 'IDENTITY' + | 'ALTER' opt_column column_name 'ADD' generated_always_as 'IDENTITY' '(' opt_sequence_option_list ')' + | 'ALTER' opt_column column_name 'ADD' generated_by_default_as 'IDENTITY' '(' opt_sequence_option_list ')' + | 'ALTER' opt_column column_name set_generated_always + | 'ALTER' opt_column column_name set_generated_default | '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 @@ -4337,6 +4343,18 @@ alter_column_visible ::= 'SET' 'VISIBLE' | 'SET' 'NOT' 'VISIBLE' +generated_always_as ::= + 'GENERATED_ALWAYS' 'ALWAYS' 'AS' + +generated_by_default_as ::= + 'GENERATED_BY_DEFAULT' 'BY' 'DEFAULT' 'AS' + +set_generated_always ::= + 'SET' 'GENERATED_ALWAYS' 'ALWAYS' + +set_generated_default ::= + 'SET' 'GENERATED_BY_DEFAULT' 'BY' 'DEFAULT' + opt_set_data ::= 'SET' 'DATA' | @@ -4765,12 +4783,6 @@ generated_as ::= 'AS' | generated_always_as -generated_always_as ::= - 'GENERATED_ALWAYS' 'ALWAYS' 'AS' - -generated_by_default_as ::= - 'GENERATED_BY_DEFAULT' 'BY' 'DEFAULT' 'AS' - frame_bound ::= 'UNBOUNDED' 'PRECEDING' | 'UNBOUNDED' 'FOLLOWING' diff --git a/pkg/sql/alter_table.go b/pkg/sql/alter_table.go index 98897c86964d..e840773909d8 100644 --- a/pkg/sql/alter_table.go +++ b/pkg/sql/alter_table.go @@ -1057,6 +1057,129 @@ func applyColumnMutation( "column %q is not a stored computed column", col.GetName()) } col.ColumnDesc().ComputeExpr = nil + + case *tree.AlterTableAddIdentity: + if typ := col.GetType(); typ == nil || typ.InternalType.Family != types.IntFamily { + return pgerror.Newf( + pgcode.InvalidParameterValue, + "column %q of relation %q type must be an integer type", col.GetName(), tableDesc.GetName()) + } + if col.IsGeneratedAsIdentity() { + return pgerror.Newf(pgcode.ObjectNotInPrerequisiteState, + "column %q of relation %q is already an identity column", + col.GetName(), tableDesc.GetName()) + } + if col.HasDefault() { + return pgerror.Newf(pgcode.ObjectNotInPrerequisiteState, + "column %q of relation %q already has a default value", col.GetName(), tableDesc.GetName()) + } + if col.IsComputed() { + return pgerror.Newf(pgcode.ObjectNotInPrerequisiteState, + "column %q of relation %q already has a computed value", col.GetName(), tableDesc.GetName()) + } + if col.IsNullable() { + return pgerror.Newf(pgcode.ObjectNotInPrerequisiteState, + "column %q of relation %q must be declared NOT NULL before identity can be added", col.GetName(), tableDesc.GetName()) + } + if col.HasOnUpdate() { + return pgerror.Newf(pgcode.ObjectNotInPrerequisiteState, + "column %q of relation %q already has an update expression", col.GetName(), tableDesc.GetName()) + } + + // Create column definition for identity column + q := []tree.NamedColumnQualification{{Qualification: t.Qualification}} + colDef, err := tree.NewColumnTableDef(tree.Name(col.GetName()), col.GetType(), false /* isSerial */, q) + if err != nil { + return err + } + newDef, prefix, seqName, seqOpts, err := params.p.processSerialLikeInColumnDef(params.ctx, colDef, tn) + if err != nil { + return err + } + if seqName == nil { + return errors.Newf("failed to create sequence %q for new identity column %q in %q", seqName, col.ColName(), tn) + } + colDef = newDef + + colOwnedSeqDesc, err := doCreateSequence( + ctx, + params.p, + params.SessionData(), + prefix.Database, + prefix.Schema, + seqName, + tree.PersistencePermanent, + seqOpts, + fmt.Sprintf("creating sequence %q for new identity column %q in %q", seqName, col.ColName(), tn), + ) + if err != nil { + return err + } + + typedExpr, _, err := sanitizeColumnExpression(params, colDef.DefaultExpr.Expr, col, tree.ColumnDefaultExprInSetDefault) + if err != nil { + return err + } + + changedSeqDescs, err := maybeAddSequenceDependencies( + params.ctx, + params.p.ExecCfg().Settings, + params.p, + tableDesc, + col.ColumnDesc(), + typedExpr, + nil, /* backrefs */ + tabledesc.DefaultExpr, + ) + if err != nil { + return err + } + for _, changedSeqDesc := range changedSeqDescs { + // `colOwnedSeqDesc` and `changedSeqDesc` should refer to a same instance. + // But we still want to use the right copy to write a schema change for by + // using `changedSeqDesc` just in case the assumption became false in the + // future. + if colOwnedSeqDesc != nil && colOwnedSeqDesc.ID == changedSeqDesc.ID { + if err := setSequenceOwner(changedSeqDesc, col.ColName(), tableDesc); err != nil { + return err + } + } + if err := params.p.writeSchemaChange( + params.ctx, changedSeqDesc, descpb.InvalidMutationID, tree.AsStringWithFQNames(t, params.Ann()), + ); err != nil { + return err + } + } + + // Set column description to identity + switch (t.Qualification).(type) { + case *tree.GeneratedAlwaysAsIdentity: + col.ColumnDesc().GeneratedAsIdentityType = catpb.GeneratedAsIdentityType_GENERATED_ALWAYS + case *tree.GeneratedByDefAsIdentity: + col.ColumnDesc().GeneratedAsIdentityType = catpb.GeneratedAsIdentityType_GENERATED_BY_DEFAULT + } + seqOptsStr := tree.Serialize(&seqOpts) + col.ColumnDesc().GeneratedAsIdentitySequenceOption = &seqOptsStr + + case *tree.AlterTableSetIdentity: + if !col.IsGeneratedAsIdentity() { + return pgerror.Newf(pgcode.ObjectNotInPrerequisiteState, + "column %q of relation %q is not an identity column", + col.GetName(), tableDesc.GetName()) + } + + switch t.GeneratedAsIdentityType { + case tree.GeneratedAlways: + if col.IsGeneratedAlwaysAsIdentity() { + return nil + } + col.ColumnDesc().GeneratedAsIdentityType = catpb.GeneratedAsIdentityType_GENERATED_ALWAYS + case tree.GeneratedByDefault: + if col.IsGeneratedByDefaultAsIdentity() { + return nil + } + col.ColumnDesc().GeneratedAsIdentityType = catpb.GeneratedAsIdentityType_GENERATED_BY_DEFAULT + } } return nil } diff --git a/pkg/sql/importer/import_stmt_test.go b/pkg/sql/importer/import_stmt_test.go index cb42099626fb..ca674e1122f3 100644 --- a/pkg/sql/importer/import_stmt_test.go +++ b/pkg/sql/importer/import_stmt_test.go @@ -5982,14 +5982,6 @@ func TestImportPgDumpIgnoredStmts(t *testing.T) { $_$; ALTER FUNCTION public.isnumeric(text) OWNER TO roland; - ALTER TABLE "database"."table" ALTER COLUMN "Id" ADD GENERATED BY DEFAULT AS IDENTITY ( - SEQUENCE NAME "database"."sequencename" - START WITH 1 - INCREMENT BY 1 - NO MINVALUE - NO MAXVALUE - CACHE 1 - ); COPY db.table (col1, col2, col3, col4) FROM '$$PATH$$/3057.dat'; GRANT USAGE ON SCHEMA "schemaname" TO davidt WITH GRANT OPTION; diff --git a/pkg/sql/logictest/testdata/logic_test/alter_table b/pkg/sql/logictest/testdata/logic_test/alter_table index aa5fc92704d4..dcb4b9fe9315 100644 --- a/pkg/sql/logictest/testdata/logic_test/alter_table +++ b/pkg/sql/logictest/testdata/logic_test/alter_table @@ -3630,3 +3630,145 @@ DROP CONSTRAINT "t_120017_pkey", ADD CONSTRAINT "t_120017_pkey" PRIMARY KEY (a, c) subtest end + +subtest identity_column + +statement ok +CREATE TABLE t_add_generated ( + a int NOT NULL, + b int NOT NULL, + c int, + d STRING NOT NULL, + e INT DEFAULT 1, + FAMILY (a,b,c,d,e) +) + +statement ok +ALTER TABLE t_add_generated ALTER COLUMN a ADD GENERATED BY DEFAULT AS IDENTITY (START WITH 2 INCREMENT 3); + +query T +SELECT create_statement FROM [SHOW CREATE TABLE t_add_generated] +---- +CREATE TABLE public.t_add_generated ( + a INT8 NOT NULL GENERATED BY DEFAULT AS IDENTITY (START WITH 2 INCREMENT 3), + b INT8 NOT NULL, + c INT8 NULL, + d STRING NOT NULL, + e INT8 NULL DEFAULT 1:::INT8, + rowid INT8 NOT VISIBLE NOT NULL DEFAULT unique_rowid(), + CONSTRAINT t_add_generated_pkey PRIMARY KEY (rowid ASC), + FAMILY fam_0_a_b_c_d_e_rowid (a, b, c, d, e, rowid) +) + +statement ok +ALTER TABLE t_add_generated ALTER COLUMN b ADD GENERATED ALWAYS AS IDENTITY (START WITH 2 INCREMENT 3); + +query T +SELECT create_statement FROM [SHOW CREATE TABLE t_add_generated] +---- +CREATE TABLE public.t_add_generated ( + a INT8 NOT NULL GENERATED BY DEFAULT AS IDENTITY (START WITH 2 INCREMENT 3), + b INT8 NOT NULL GENERATED ALWAYS AS IDENTITY (START WITH 2 INCREMENT 3), + c INT8 NULL, + d STRING NOT NULL, + e INT8 NULL DEFAULT 1:::INT8, + rowid INT8 NOT VISIBLE NOT NULL DEFAULT unique_rowid(), + CONSTRAINT t_add_generated_pkey PRIMARY KEY (rowid ASC), + FAMILY fam_0_a_b_c_d_e_rowid (a, b, c, d, e, rowid) +) + +query error pq: column "c" of relation "t_add_generated" must be declared NOT NULL before identity can be added +ALTER TABLE t_add_generated ALTER COLUMN c ADD GENERATED ALWAYS AS IDENTITY; + +query error pq: column "e" of relation "t_add_generated" already has a default value +ALTER TABLE t_add_generated ALTER COLUMN e ADD GENERATED ALWAYS AS IDENTITY; + +query error pq: column "a" of relation "t_add_generated" is already an identity column +ALTER TABLE t_add_generated ALTER COLUMN a ADD GENERATED ALWAYS AS IDENTITY; + +query error pq: column "d" of relation "t_add_generated" type must be an integer type +ALTER TABLE t_add_generated ALTER COLUMN d ADD GENERATED ALWAYS AS IDENTITY; + +statement ok +INSERT INTO t_add_generated (d) VALUES ('11'), ('12'), ('13'); + +statement ok +INSERT INTO t_add_generated (a,d) VALUES (21,'21'), (22,'22'), (23,'23'); + +statement error pq: cannot insert into column "b"\nDETAIL: Column "b" is an identity column defined as GENERATED ALWAYS +INSERT INTO t_add_generated (b,d) VALUES (31,'31'), (32,'32'), (33,'33'); + +query IIITI +SELECT * FROM t_add_generated ORDER BY a +---- +2 2 NULL 11 1 +5 5 NULL 12 1 +8 8 NULL 13 1 +21 11 NULL 21 1 +22 14 NULL 22 1 +23 17 NULL 23 1 + +statement ok +CREATE TABLE t_set_generated ( + a int GENERATED ALWAYS AS IDENTITY (START WITH 2 INCREMENT 3), + b int GENERATED BY DEFAULT AS IDENTITY (START WITH 2 INCREMENT 3), + c int, + FAMILY (a,b,c) +); + +statement ok +ALTER TABLE t_set_generated ALTER COLUMN a SET GENERATED BY DEFAULT; + +query T +SELECT create_statement FROM [SHOW CREATE TABLE t_set_generated] +---- +CREATE TABLE public.t_set_generated ( + a INT8 NOT NULL GENERATED BY DEFAULT AS IDENTITY (START WITH 2 INCREMENT 3), + b INT8 NOT NULL GENERATED BY DEFAULT AS IDENTITY (START WITH 2 INCREMENT 3), + c INT8 NULL, + rowid INT8 NOT VISIBLE NOT NULL DEFAULT unique_rowid(), + CONSTRAINT t_set_generated_pkey PRIMARY KEY (rowid ASC), + FAMILY fam_0_a_b_c_rowid (a, b, c, rowid) +) + +statement ok +ALTER TABLE t_set_generated ALTER COLUMN b SET GENERATED ALWAYS; + +query T +SELECT create_statement FROM [SHOW CREATE TABLE t_set_generated] +---- +CREATE TABLE public.t_set_generated ( + a INT8 NOT NULL GENERATED BY DEFAULT AS IDENTITY (START WITH 2 INCREMENT 3), + b INT8 NOT NULL GENERATED ALWAYS AS IDENTITY (START WITH 2 INCREMENT 3), + c INT8 NULL, + rowid INT8 NOT VISIBLE NOT NULL DEFAULT unique_rowid(), + CONSTRAINT t_set_generated_pkey PRIMARY KEY (rowid ASC), + FAMILY fam_0_a_b_c_rowid (a, b, c, rowid) +) + +statement error pq: column "c" of relation "t_set_generated" is not an identity column +ALTER TABLE t_set_generated ALTER COLUMN c SET GENERATED BY DEFAULT; + +statement error pq: column "c" of relation "t_set_generated" is not an identity column +ALTER TABLE t_set_generated ALTER COLUMN c SET GENERATED ALWAYS; + +statement ok +INSERT INTO t_set_generated DEFAULT VALUES; + +statement ok +INSERT INTO t_set_generated DEFAULT VALUES; + +statement ok +INSERT INTO t_set_generated (a) VALUES (3); + +statement error pq: cannot insert into column "b"\nDETAIL: Column "b" is an identity column defined as GENERATED ALWAYS +INSERT INTO t_set_generated (b) VALUES (4); + +query III +SELECT * FROM t_set_generated ORDER BY a +---- +2 2 NULL +3 8 NULL +5 5 NULL + +subtest end diff --git a/pkg/sql/logictest/testdata/logic_test/information_schema b/pkg/sql/logictest/testdata/logic_test/information_schema index 3ea77e465ceb..fffe0a78c1c0 100644 --- a/pkg/sql/logictest/testdata/logic_test/information_schema +++ b/pkg/sql/logictest/testdata/logic_test/information_schema @@ -3373,6 +3373,70 @@ b YES ALWAYS NO c YES BY DEFAULT NO rowid NO · NO +statement ok +CREATE DATABASE test_identity + +statement ok +SET DATABASE = test_identity + +statement ok +CREATE TABLE add_generated_as_identity ( + a INT NOT NULL, + b INT NOT NULL +) + +statement ok +ALTER TABLE add_generated_as_identity ALTER COLUMN a ADD GENERATED ALWAYS AS IDENTITY (START WITH 10 INCREMENT BY 2); + +statement ok +ALTER TABLE add_generated_as_identity ALTER COLUMN b ADD GENERATED BY DEFAULT AS IDENTITY (START WITH 10 INCREMENT BY 2); + +query TTTTTTTTTT colnames +SELECT column_name, is_identity, identity_generation, is_nullable, column_default, identity_start, identity_increment, identity_maximum, identity_minimum, identity_cycle +FROM information_schema.columns +WHERE table_schema = 'public' AND table_name = 'add_generated_as_identity' +ORDER BY column_name +---- +column_name is_identity identity_generation is_nullable column_default identity_start identity_increment identity_maximum identity_minimum identity_cycle +a YES ALWAYS NO nextval('public.add_generated_as_identity_a_seq'::REGCLASS) 10 2 9223372036854775807 1 NULL +b YES BY DEFAULT NO nextval('public.add_generated_as_identity_b_seq'::REGCLASS) 10 2 9223372036854775807 1 NULL +rowid NO · NO unique_rowid() NULL NULL NULL NULL NULL + +statement ok +CREATE TABLE set_generated_as_identity ( + a INT GENERATED ALWAYS AS IDENTITY (START WITH 10), + b INT GENERATED BY DEFAULT AS IDENTITY (START WITH 10) +) + +statement ok +ALTER TABLE set_generated_as_identity ALTER COLUMN a SET GENERATED BY DEFAULT; + +statement ok +ALTER TABLE set_generated_as_identity ALTER COLUMN b SET GENERATED ALWAYS; + +query TTTTTTTTTT colnames +SELECT column_name, is_identity, identity_generation, is_nullable, column_default, identity_start, identity_increment, identity_maximum, identity_minimum, identity_cycle +FROM information_schema.columns +WHERE table_schema = 'public' AND table_name = 'set_generated_as_identity' +ORDER BY column_name +---- +column_name is_identity identity_generation is_nullable column_default identity_start identity_increment identity_maximum identity_minimum identity_cycle +a YES BY DEFAULT NO nextval('public.set_generated_as_identity_a_seq'::REGCLASS) 10 1 9223372036854775807 1 NULL +b YES ALWAYS NO nextval('public.set_generated_as_identity_b_seq'::REGCLASS) 10 1 9223372036854775807 1 NULL +rowid NO · NO unique_rowid() NULL NULL NULL NULL NULL + +query TTTTIIITTTTT colnames +SELECT * FROM information_schema.sequences ORDER BY sequence_name +---- +sequence_catalog sequence_schema sequence_name data_type numeric_precision numeric_precision_radix numeric_scale start_value minimum_value maximum_value increment cycle_option +test_identity public add_generated_as_identity_a_seq INT8 64 2 0 10 1 9223372036854775807 2 NO +test_identity public add_generated_as_identity_b_seq INT8 64 2 0 10 1 9223372036854775807 2 NO +test_identity public set_generated_as_identity_a_seq INT8 64 2 0 10 1 9223372036854775807 1 NO +test_identity public set_generated_as_identity_b_seq INT8 64 2 0 10 1 9223372036854775807 1 NO + +statement ok +SET DATABASE = test + statement ok CREATE TABLE char_len ( a INT, b INT2, c INT4, diff --git a/pkg/sql/parser/sql.y b/pkg/sql/parser/sql.y index af27a43ed197..1a6fbcfdccfb 100644 --- a/pkg/sql/parser/sql.y +++ b/pkg/sql/parser/sql.y @@ -1860,6 +1860,8 @@ alter_ddl_stmt: // ALTER TABLE ... ALTER [COLUMN] {SET ON UPDATE | DROP ON UPDATE} // ALTER TABLE ... ALTER [COLUMN] DROP NOT NULL // ALTER TABLE ... ALTER [COLUMN] DROP STORED +// ALTER TABLE ... ALTER [COLUMN] ADD GENERATED { ALWAYS | BY DEFAULT } AS IDENTITY [ ( opt_sequence_option_list ) ] +// ALTER TABLE ... ALTER [COLUMN] SET GENERATED { ALWAYS | BY DEFAULT } // ALTER TABLE ... ALTER [COLUMN] [SET DATA] TYPE [COLLATE ] // ALTER TABLE ... ALTER PRIMARY KEY USING COLUMNS ( ) // ALTER TABLE ... RENAME TO @@ -2756,6 +2758,38 @@ alter_table_cmd: | ALTER opt_column column_name DROP NOT NULL { $$.val = &tree.AlterTableDropNotNull{Column: tree.Name($3)} + } + // ALTER TABLE ALTER [COLUMN] ADD GENERATED ALWAYS AS IDENTITY +| ALTER opt_column column_name ADD generated_always_as IDENTITY { + qualification := tree.GeneratedAlwaysAsIdentity{} + $$.val = &tree.AlterTableAddIdentity{Column: tree.Name($3), Qualification: &qualification} + } + // ALTER TABLE ALTER [COLUMN] ADD GENERATED BY DEFAULT AS IDENTITY +| ALTER opt_column column_name ADD generated_by_default_as IDENTITY { + qualification := tree.GeneratedByDefAsIdentity{} + $$.val = &tree.AlterTableAddIdentity{Column: tree.Name($3), Qualification: &qualification} + } + // ALTER TABLE ALTER [COLUMN] ADD GENERATED ALWAYS AS IDENTITY ( ) +| ALTER opt_column column_name ADD generated_always_as IDENTITY '(' opt_sequence_option_list ')' { + qualification := tree.GeneratedAlwaysAsIdentity{ + SeqOptions: $8.seqOpts(), + } + $$.val = &tree.AlterTableAddIdentity{Column: tree.Name($3), Qualification: &qualification} + } + // ALTER TABLE ALTER [COLUMN] ADD GENERATED BY DEFAULT AS IDENTITY ( ) +| ALTER opt_column column_name ADD generated_by_default_as IDENTITY '(' opt_sequence_option_list ')' { + qualification := tree.GeneratedByDefAsIdentity{ + SeqOptions: $8.seqOpts(), + } + $$.val = &tree.AlterTableAddIdentity{Column: tree.Name($3), Qualification: &qualification} +} + // ALTER TABLE ALTER [COLUMN] SET GENERATED ALWAYS +| ALTER opt_column column_name set_generated_always { + $$.val = &tree.AlterTableSetIdentity{Column: tree.Name($3), GeneratedAsIdentityType: tree.GeneratedAlways} + } + // ALTER TABLE ALTER [COLUMN] SET GENERATED BY DEFAULT +| ALTER opt_column column_name set_generated_default { + $$.val = &tree.AlterTableSetIdentity{Column: tree.Name($3), GeneratedAsIdentityType: tree.GeneratedByDefault} } // ALTER TABLE ALTER [COLUMN] DROP STORED | ALTER opt_column column_name DROP STORED @@ -10242,6 +10276,12 @@ generated_as: AS {} | generated_always_as +set_generated_always: + SET GENERATED_ALWAYS ALWAYS + +set_generated_default: + SET GENERATED_BY_DEFAULT BY DEFAULT + generated_always_as: GENERATED_ALWAYS ALWAYS AS {} diff --git a/pkg/sql/parser/testdata/alter_table b/pkg/sql/parser/testdata/alter_table index 62ee35b63149..880c2c4c42c0 100644 --- a/pkg/sql/parser/testdata/alter_table +++ b/pkg/sql/parser/testdata/alter_table @@ -1277,3 +1277,51 @@ ALTER TABLE a ALTER COLUMN b SET DATA TYPE "A Nice Name For A Type 🌠" -- norm ALTER TABLE a ALTER COLUMN b SET DATA TYPE "A Nice Name For A Type 🌠" -- fully parenthesized ALTER TABLE a ALTER COLUMN b SET DATA TYPE "A Nice Name For A Type 🌠" -- literals removed ALTER TABLE _ ALTER COLUMN _ SET DATA TYPE _ -- identifiers removed + +parse +ALTER TABLE a ALTER COLUMN b ADD GENERATED ALWAYS AS IDENTITY +---- +ALTER TABLE a ALTER COLUMN b ADD GENERATED ALWAYS AS IDENTITY +ALTER TABLE a ALTER COLUMN b ADD GENERATED ALWAYS AS IDENTITY -- fully parenthesized +ALTER TABLE a ALTER COLUMN b ADD GENERATED ALWAYS AS IDENTITY -- literals removed +ALTER TABLE _ ALTER COLUMN _ ADD GENERATED ALWAYS AS IDENTITY -- identifiers removed + +parse +ALTER TABLE a ALTER COLUMN b ADD GENERATED BY DEFAULT AS IDENTITY +---- +ALTER TABLE a ALTER COLUMN b ADD GENERATED BY DEFAULT AS IDENTITY +ALTER TABLE a ALTER COLUMN b ADD GENERATED BY DEFAULT AS IDENTITY -- fully parenthesized +ALTER TABLE a ALTER COLUMN b ADD GENERATED BY DEFAULT AS IDENTITY -- literals removed +ALTER TABLE _ ALTER COLUMN _ ADD GENERATED BY DEFAULT AS IDENTITY -- identifiers removed + +parse +ALTER TABLE a ALTER COLUMN b ADD GENERATED ALWAYS AS IDENTITY (START WITH 10) +---- +ALTER TABLE a ALTER COLUMN b ADD GENERATED ALWAYS AS IDENTITY ( START WITH 10 ) -- normalized! +ALTER TABLE a ALTER COLUMN b ADD GENERATED ALWAYS AS IDENTITY ( START WITH 10 ) -- fully parenthesized +ALTER TABLE a ALTER COLUMN b ADD GENERATED ALWAYS AS IDENTITY ( START WITH 0 ) -- literals removed +ALTER TABLE _ ALTER COLUMN _ ADD GENERATED ALWAYS AS IDENTITY ( START WITH 10 ) -- identifiers removed + +parse +ALTER TABLE a ALTER COLUMN b ADD GENERATED BY DEFAULT AS IDENTITY (START WITH 10) +---- +ALTER TABLE a ALTER COLUMN b ADD GENERATED BY DEFAULT AS IDENTITY ( START WITH 10 ) -- normalized! +ALTER TABLE a ALTER COLUMN b ADD GENERATED BY DEFAULT AS IDENTITY ( START WITH 10 ) -- fully parenthesized +ALTER TABLE a ALTER COLUMN b ADD GENERATED BY DEFAULT AS IDENTITY ( START WITH 0 ) -- literals removed +ALTER TABLE _ ALTER COLUMN _ ADD GENERATED BY DEFAULT AS IDENTITY ( START WITH 10 ) -- identifiers removed + +parse +ALTER TABLE a ALTER COLUMN b SET GENERATED ALWAYS +---- +ALTER TABLE a ALTER COLUMN b SET GENERATED ALWAYS +ALTER TABLE a ALTER COLUMN b SET GENERATED ALWAYS -- fully parenthesized +ALTER TABLE a ALTER COLUMN b SET GENERATED ALWAYS -- literals removed +ALTER TABLE _ ALTER COLUMN _ SET GENERATED ALWAYS -- identifiers removed + +parse +ALTER TABLE a ALTER COLUMN b SET GENERATED BY DEFAULT +---- +ALTER TABLE a ALTER COLUMN b SET GENERATED BY DEFAULT +ALTER TABLE a ALTER COLUMN b SET GENERATED BY DEFAULT -- fully parenthesized +ALTER TABLE a ALTER COLUMN b SET GENERATED BY DEFAULT -- literals removed +ALTER TABLE _ ALTER COLUMN _ SET GENERATED BY DEFAULT -- identifiers removed diff --git a/pkg/sql/sem/tree/alter_table.go b/pkg/sql/sem/tree/alter_table.go index 7132e93fe5c3..812ed74bd5e9 100644 --- a/pkg/sql/sem/tree/alter_table.go +++ b/pkg/sql/sem/tree/alter_table.go @@ -76,6 +76,8 @@ func (*AlterTablePartitionByTable) alterTableCmd() {} func (*AlterTableInjectStats) alterTableCmd() {} func (*AlterTableSetStorageParams) alterTableCmd() {} func (*AlterTableResetStorageParams) alterTableCmd() {} +func (*AlterTableAddIdentity) alterTableCmd() {} +func (*AlterTableSetIdentity) alterTableCmd() {} var _ AlterTableCmd = &AlterTableAddColumn{} var _ AlterTableCmd = &AlterTableAddConstraint{} @@ -96,6 +98,8 @@ var _ AlterTableCmd = &AlterTablePartitionByTable{} var _ AlterTableCmd = &AlterTableInjectStats{} var _ AlterTableCmd = &AlterTableSetStorageParams{} var _ AlterTableCmd = &AlterTableResetStorageParams{} +var _ AlterTableCmd = &AlterTableAddIdentity{} +var _ AlterTableCmd = &AlterTableSetIdentity{} // ColumnMutationCmd is the subset of AlterTableCmds that modify an // existing column. @@ -738,6 +742,70 @@ func (node *AlterTableOwner) Format(ctx *FmtCtx) { ctx.FormatNode(&node.Owner) } +// AlterTableAddIdentity represents commands to alter a column to an identity. +type AlterTableAddIdentity struct { + Column Name + Qualification ColumnQualification +} + +// GetColumn implemnets the ColumnMutationCmd interface. +func (node *AlterTableAddIdentity) GetColumn() Name { + return node.Column +} + +// TelemetryName implements the AlterTableCmd interface. +func (node *AlterTableAddIdentity) TelemetryName() string { + return "add_identity" +} + +// Format implements the NodeFormatter interface. +func (node *AlterTableAddIdentity) Format(ctx *FmtCtx) { + ctx.WriteString(" ALTER COLUMN ") + ctx.FormatNode(&node.Column) + var options SequenceOptions + switch t := (node.Qualification).(type) { + case *GeneratedAlwaysAsIdentity: + ctx.WriteString(" ADD GENERATED ALWAYS AS IDENTITY") + options = t.SeqOptions + case *GeneratedByDefAsIdentity: + ctx.WriteString(" ADD GENERATED BY DEFAULT AS IDENTITY") + options = t.SeqOptions + } + if len(options) > 0 { + ctx.WriteString(" (") + ctx.FormatNode(&options) + ctx.WriteString(" )") + } +} + +// AlterTableSetIdentity represents commands to alter a column identity type. +type AlterTableSetIdentity struct { + Column Name + GeneratedAsIdentityType GeneratedIdentityType +} + +// GetColumn implemnets the ColumnMutationCmd interface. +func (node *AlterTableSetIdentity) GetColumn() Name { + return node.Column +} + +// TelemetryName implements the AlterTableCmd interface. +func (node *AlterTableSetIdentity) TelemetryName() string { + return "set_identity" +} + +// Format implements the NodeFormatter interface. +func (node *AlterTableSetIdentity) Format(ctx *FmtCtx) { + ctx.WriteString(" ALTER COLUMN ") + ctx.FormatNode(&node.Column) + switch node.GeneratedAsIdentityType { + case GeneratedAlways: + ctx.WriteString(" SET GENERATED ALWAYS") + case GeneratedByDefault: + ctx.WriteString(" SET GENERATED BY DEFAULT") + } +} + // GetTableType returns a string representing the type of table the command // is operating on. // It is assumed if the table is not a sequence or a view, then it is a diff --git a/pkg/sql/sem/tree/stmt.go b/pkg/sql/sem/tree/stmt.go index 396e2ab271fe..af007d321ad2 100644 --- a/pkg/sql/sem/tree/stmt.go +++ b/pkg/sql/sem/tree/stmt.go @@ -2275,6 +2275,7 @@ func (n *AlterTableDropColumn) String() string { return AsString( func (n *AlterTableDropConstraint) String() string { return AsString(n) } func (n *AlterTableDropNotNull) String() string { return AsString(n) } func (n *AlterTableDropStored) String() string { return AsString(n) } +func (n *AlterTableAddIdentity) String() string { return AsString(n) } func (n *AlterTableLocality) String() string { return AsString(n) } func (n *AlterTableSetDefault) String() string { return AsString(n) } func (n *AlterTableSetVisible) String() string { return AsString(n) } diff --git a/pkg/sql/sequence_test.go b/pkg/sql/sequence_test.go index dce1a0bed800..865d6fabccfa 100644 --- a/pkg/sql/sequence_test.go +++ b/pkg/sql/sequence_test.go @@ -184,6 +184,20 @@ CREATE TABLE t.test(a INT PRIMARY KEY, b INT)`); err != nil { } assertColumnOwnsSequences(t, kvDB, "t", "test", 0 /* colIdx */, nil /* seqNames */) assertColumnOwnsSequences(t, kvDB, "t", "test", 1 /* colIdx */, nil /* seqNames */) + + // Ensure identity column owns a sequence + if _, err := sqlConn.Exec("CREATE TABLE t.test2(a INT GENERATED ALWAYS AS IDENTITY, b INT NOT NULL)"); err != nil { + t.Fatal(err) + } + assertColumnOwnsSequences(t, kvDB, "t", "test2", 0 /* colIdx */, []string{"test2_a_seq"}) + assertColumnOwnsSequences(t, kvDB, "t", "test2", 1 /* colIdx */, nil /* seqNames */) + + // Ensure adding identity column owns a sequence + if _, err := sqlConn.Exec("ALTER TABLE t.test2 ALTER COLUMN b ADD GENERATED ALWAYS AS IDENTITY;"); err != nil { + t.Fatal(err) + } + assertColumnOwnsSequences(t, kvDB, "t", "test2", 0 /* colIdx */, []string{"test2_a_seq"}) + assertColumnOwnsSequences(t, kvDB, "t", "test2", 1 /* colIdx */, []string{"test2_b_seq"}) } // assertColumnOwnsSequences ensures that the column at (DbName, tbName, colIdx)