spark-instrumented-optimizer/docs/sql-ref-syntax-ddl-alter-table.md
Huaxin Gao 75da05038b [MINOR][SQL][DOCS] Remove two leading spaces from sql tables
### What changes were proposed in this pull request?
Remove two leading spaces from sql tables.

### Why are the changes needed?

Follow the format of other references such as https://docs.snowflake.com/en/sql-reference/constructs/join.html, https://docs.oracle.com/cd/B19306_01/server.102/b14200/statements_10002.htm, https://www.postgresql.org/docs/10/sql-select.html.

### Does this PR introduce any user-facing change?

before
```
SELECT * FROM  test;
  +-+
  ...
  +-+
```
after
```
SELECT * FROM  test;
+-+
...
+-+
```

### How was this patch tested?
Manually build and check

Closes #28348 from huaxingao/sql-format.

Authored-by: Huaxin Gao <huaxing@us.ibm.com>
Signed-off-by: gatorsmile <gatorsmile@gmail.com>
2020-05-01 10:11:43 -07:00

12 KiB

layout title displayTitle license
global ALTER TABLE ALTER TABLE Licensed to the Apache Software Foundation (ASF) under one or more contributor license agreements. See the NOTICE file distributed with this work for additional information regarding copyright ownership. The ASF licenses this file to You under the Apache License, Version 2.0 (the "License"); you may not use this file except in compliance with the License. You may obtain a copy of the License at http://www.apache.org/licenses/LICENSE-2.0 Unless required by applicable law or agreed to in writing, software distributed under the License is distributed on an "AS IS" BASIS, WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. See the License for the specific language governing permissions and limitations under the License.

Description

ALTER TABLE statement changes the schema or properties of a table.

RENAME

ALTER TABLE RENAME TO statement changes the table name of an existing table in the database.

Syntax

{% highlight sql %} ALTER TABLE table_identifier RENAME TO table_identifier

ALTER TABLE table_identifier partition_spec RENAME TO partition_spec {% endhighlight %}

Parameters

table_identifier
Specifies a table name, which may be optionally qualified with a database name.

Syntax: [ database_name. ] table_name
partition_spec
Partition to be renamed.

Syntax: PARTITION ( partition_col_name = partition_col_val [ , ... ] )

ADD COLUMNS

ALTER TABLE ADD COLUMNS statement adds mentioned columns to an existing table.

Syntax

{% highlight sql %} ALTER TABLE table_identifier ADD COLUMNS ( col_spec [ , ... ] ) {% endhighlight %}

Parameters

table_identifier
Specifies a table name, which may be optionally qualified with a database name.

Syntax: [ database_name. ] table_name
COLUMNS ( col_spec )
Specifies the columns to be added.

ALTER OR CHANGE COLUMN

ALTER TABLE ALTER COLUMN or ALTER TABLE CHANGE COLUMN statement changes column's comment.

Syntax

{% highlight sql %} ALTER TABLE table_identifier { ALTER | CHANGE } [ COLUMN ] col_spec alterColumnAction {% endhighlight %}

Parameters

table_identifier
Specifies a table name, which may be optionally qualified with a database name.

Syntax: [ database_name. ] table_name
COLUMN col_spec
Specifies the column to be altered or be changed.
alterColumnAction
Change the comment string.

Syntax: COMMENT STRING

ADD AND DROP PARTITION

ADD PARTITION

ALTER TABLE ADD statement adds partition to the partitioned table.

Syntax

{% highlight sql %} ALTER TABLE table_identifier ADD [IF NOT EXISTS] ( partition_spec [ partition_spec ... ] ) {% endhighlight %}

Parameters
table_identifier
Specifies a table name, which may be optionally qualified with a database name.

Syntax: [ database_name. ] table_name
partition_spec
Partition to be added.

Syntax: PARTITION ( partition_col_name = partition_col_val [ , ... ] )

DROP PARTITION

ALTER TABLE DROP statement drops the partition of the table.

Syntax

{% highlight sql %} ALTER TABLE table_identifier DROP [ IF EXISTS ] partition_spec [PURGE] {% endhighlight %}

Parameters
table_identifier
Specifies a table name, which may be optionally qualified with a database name.

Syntax: [ database_name. ] table_name
partition_spec
Partition to be dropped.

Syntax: PARTITION ( partition_col_name = partition_col_val [ , ... ] )

SET AND UNSET

SET TABLE PROPERTIES

ALTER TABLE SET command is used for setting the table properties. If a particular property was already set, this overrides the old value with the new one.

ALTER TABLE UNSET is used to drop the table property.

Syntax

{% highlight sql %} -- Set Table Properties ALTER TABLE table_identifier SET TBLPROPERTIES ( key1 = val1, key2 = val2, ... )

-- Unset Table Properties ALTER TABLE table_identifier UNSET TBLPROPERTIES [ IF EXISTS ] ( key1, key2, ... ) {% endhighlight %}

SET SERDE

ALTER TABLE SET command is used for setting the SERDE or SERDE properties in Hive tables. If a particular property was already set,
this overrides the old value with the new one.

Syntax

{% highlight sql %} -- Set SERDE Properties ALTER TABLE table_identifier [ partition_spec ] SET SERDEPROPERTIES ( key1 = val1, key2 = val2, ... )

ALTER TABLE table_identifier [ partition_spec ] SET SERDE serde_class_name [ WITH SERDEPROPERTIES ( key1 = val1, key2 = val2, ... ) ]

{% endhighlight %}

SET LOCATION And SET FILE FORMAT

ALTER TABLE SET command can also be used for changing the file location and file format for existing tables.

Syntax

{% highlight sql %} -- Changing File Format ALTER TABLE table_identifier [ partition_spec ] SET FILEFORMAT file_format

-- Changing File Location ALTER TABLE table_identifier [ partition_spec ] SET LOCATION 'new_location' {% endhighlight %}

Parameters

table_identifier
Specifies a table name, which may be optionally qualified with a database name.

Syntax: [ database_name. ] table_name
partition_spec
Specifies the partition on which the property has to be set.

Syntax: PARTITION ( partition_col_name = partition_col_val [ , ... ] )
SERDEPROPERTIES ( key1 = val1, key2 = val2, ... )
Specifies the SERDE properties to be set.

Examples

{% highlight sql %} -- RENAME table DESC student; +-----------------------+---------+-------+ | col_name|data_type|comment| +-----------------------+---------+-------+ | name| string| NULL| | rollno| int| NULL| | age| int| NULL| |# Partition Information| | | | # col_name|data_type|comment| | age| int| NULL| +-----------------------+---------+-------+

ALTER TABLE Student RENAME TO StudentInfo;

-- After Renaming the table DESC StudentInfo; +-----------------------+---------+-------+ | col_name|data_type|comment| +-----------------------+---------+-------+ | name| string| NULL| | rollno| int| NULL| | age| int| NULL| |# Partition Information| | | | # col_name|data_type|comment| | age| int| NULL| +-----------------------+---------+-------+

-- RENAME partition

SHOW PARTITIONS StudentInfo; +---------+ |partition| +---------+ | age=10| | age=11| | age=12| +---------+

ALTER TABLE default.StudentInfo PARTITION (age='10') RENAME TO PARTITION (age='15');

-- After renaming Partition SHOW PARTITIONS StudentInfo; +---------+ |partition| +---------+ | age=11| | age=12| | age=15| +---------+

-- Add new columns to a table DESC StudentInfo; +-----------------------+---------+-------+ | col_name|data_type|comment| +-----------------------+---------+-------+ | name| string| NULL| | rollno| int| NULL| | age| int| NULL| |# Partition Information| | | | # col_name|data_type|comment| | age| int| NULL| +-----------------------+---------+-------+

ALTER TABLE StudentInfo ADD columns (LastName string, DOB timestamp);

-- After Adding New columns to the table DESC StudentInfo; +-----------------------+---------+-------+ | col_name|data_type|comment| +-----------------------+---------+-------+ | name| string| NULL| | rollno| int| NULL| | LastName| string| NULL| | DOB|timestamp| NULL| | age| int| NULL| |# Partition Information| | | | # col_name|data_type|comment| | age| int| NULL| +-----------------------+---------+-------+

-- Add a new partition to a table SHOW PARTITIONS StudentInfo; +---------+ |partition| +---------+ | age=11| | age=12| | age=15| +---------+

ALTER TABLE StudentInfo ADD IF NOT EXISTS PARTITION (age=18);

-- After adding a new partition to the table SHOW PARTITIONS StudentInfo; +---------+ |partition| +---------+ | age=11| | age=12| | age=15| | age=18| +---------+

-- Drop a partition from the table SHOW PARTITIONS StudentInfo; +---------+ |partition| +---------+ | age=11| | age=12| | age=15| | age=18| +---------+

ALTER TABLE StudentInfo DROP IF EXISTS PARTITION (age=18);

-- After dropping the partition of the table SHOW PARTITIONS StudentInfo; +---------+ |partition| +---------+ | age=11| | age=12| | age=15| +---------+

-- Adding multiple partitions to the table SHOW PARTITIONS StudentInfo; +---------+ |partition| +---------+ | age=11| | age=12| | age=15| +---------+

ALTER TABLE StudentInfo ADD IF NOT EXISTS PARTITION (age=18) PARTITION (age=20);

-- After adding multiple partitions to the table SHOW PARTITIONS StudentInfo; +---------+ |partition| +---------+ | age=11| | age=12| | age=15| | age=18| | age=20| +---------+

-- ALTER OR CHANGE COLUMNS DESC StudentInfo; +-----------------------+---------+-------+ | col_name|data_type|comment| +-----------------------+---------+-------+ | name| string| NULL| | rollno| int| NULL| | LastName| string| NULL| | DOB|timestamp| NULL| | age| int| NULL| |# Partition Information| | | | # col_name|data_type|comment| | age| int| NULL| +-----------------------+---------+-------+

ALTER TABLE StudentInfo ALTER COLUMN name COMMENT "new comment";

--After ALTER or CHANGE COLUMNS DESC StudentInfo; +-----------------------+---------+-----------+ | col_name|data_type| comment| +-----------------------+---------+-----------+ | name| string|new comment| | rollno| int| NULL| | LastName| string| NULL| | DOB|timestamp| NULL| | age| int| NULL| |# Partition Information| | | | # col_name|data_type| comment| | age| int| NULL| +-----------------------+---------+-----------+

-- Change the fileformat ALTER TABLE loc_orc SET fileformat orc;

ALTER TABLE p1 partition (month=2, day=2) SET fileformat parquet;

-- Change the file Location ALTER TABLE dbx.tab1 PARTITION (a='1', b='2') SET LOCATION '/path/to/part/ways'

-- SET SERDE/ SERDE Properties ALTER TABLE test_tab SET SERDE 'org.apache.hadoop.hive.serde2.columnar.LazyBinaryColumnarSerDe';

ALTER TABLE dbx.tab1 SET SERDE 'org.apache.hadoop' WITH SERDEPROPERTIES ('k' = 'v', 'kay' = 'vee')

-- SET TABLE PROPERTIES ALTER TABLE dbx.tab1 SET TBLPROPERTIES ('winner' = 'loser')

-- DROP TABLE PROPERTIES ALTER TABLE dbx.tab1 UNSET TBLPROPERTIES ('winner') {% endhighlight %}