Skip to content

Commit 2adde97

Browse files
authored
add alter table connection (#2368)
1 parent a6ca98b commit 2adde97

File tree

2 files changed

+146
-65
lines changed

2 files changed

+146
-65
lines changed
Lines changed: 94 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,94 @@
1+
---
2+
title: ALTER TABLE CONNECTION
3+
sidebar_position: 6
4+
---
5+
import FunctionDescription from '@site/src/components/FunctionDescription';
6+
7+
<FunctionDescription description="Introduced or updated: v1.2.750"/>
8+
9+
Updates the connection settings for an external table.
10+
11+
## Syntax
12+
13+
```sql
14+
ALTER TABLE [ <database_name>. ]<table_name> CONNECTION = ( connection_name = '<connection_name>' )
15+
```
16+
17+
| Parameter | Description | Required |
18+
|-----------|-------------|----------|
19+
| connection_name | Name of the connection to be used for the external table. The connection must already exist in the system. | Yes |
20+
21+
## Usage Notes
22+
23+
When using the ALTER TABLE CONNECTION command, only credential-related settings can be changed, including `access_key_id`, `secret_access_key`, and `role_arn`. Changes to other connection parameters such as `bucket`, `region`, or `root` will be ignored.
24+
25+
This command is particularly useful when credentials need to be rotated or when IAM roles change. The specified connection must already exist in the system before it can be used with this command.
26+
27+
## Security Best Practices
28+
29+
When working with external tables, AWS IAM roles provide significant security advantages over access keys:
30+
31+
- **No stored credentials**: Eliminates the need to store access keys in your configuration
32+
- **Automatic rotation**: Handles credential rotation automatically
33+
- **Fine-grained control**: Allows for more precise access control
34+
35+
To use IAM roles with Databend Cloud, see [Creating External Stage with AWS IAM Role](/guides/load-data/stage/aws-iam-role) for instructions.
36+
37+
## Examples
38+
39+
### Updating Connection for an External Table
40+
41+
This example creates an external table with an initial connection, then updates it to use a different connection:
42+
43+
```sql
44+
-- Create two connections with different credentials
45+
CREATE CONNECTION external_table_conn
46+
STORAGE_TYPE = 's3'
47+
ACCESS_KEY_ID = '<your-access-key-id>'
48+
SECRET_ACCESS_KEY = '<your-secret-access-key>';
49+
50+
CREATE CONNECTION external_table_conn_new
51+
STORAGE_TYPE = 's3'
52+
ACCESS_KEY_ID = '<your-new-access-key-id>'
53+
SECRET_ACCESS_KEY = '<your-new-secret-access-key>';
54+
55+
-- Create an external table using the first connection
56+
CREATE OR REPLACE TABLE external_table_test (
57+
id INTEGER,
58+
name VARCHAR,
59+
age INT
60+
)
61+
's3://testbucket/13_fuse_external_table/'
62+
CONNECTION=(connection_name = 'external_table_conn');
63+
64+
-- Update the table to use the new connection with rotated credentials
65+
ALTER TABLE external_table_test CONNECTION=( connection_name = 'external_table_conn_new' );
66+
```
67+
68+
### Updating Connection for an External Table with IAM Role
69+
70+
This example demonstrates migrating from access key authentication to IAM role authentication:
71+
72+
```sql
73+
-- Create an external table with access key authentication
74+
CREATE CONNECTION s3_access_key_conn
75+
STORAGE_TYPE = 's3'
76+
ACCESS_KEY_ID = '<your-access-key-id>'
77+
SECRET_ACCESS_KEY = '<your-secret-access-key>';
78+
79+
CREATE TABLE sales_data (
80+
order_id INTEGER,
81+
product_name VARCHAR,
82+
quantity INT
83+
)
84+
's3://sales-bucket/data/'
85+
CONNECTION=(connection_name = 's3_access_key_conn');
86+
87+
-- Later, create a new connection using IAM role authentication
88+
CREATE CONNECTION s3_role_conn
89+
STORAGE_TYPE = 's3'
90+
ROLE_ARN = 'arn:aws:iam::123456789012:role/databend-access';
91+
92+
-- Update the table to use the IAM role connection instead
93+
ALTER TABLE sales_data CONNECTION=( connection_name = 's3_role_conn' );
94+
```
Lines changed: 52 additions & 65 deletions
Original file line numberDiff line numberDiff line change
@@ -1,71 +1,58 @@
11
---
2-
title: Table
2+
title: Table Commands
33
---
44

5-
This page compiles crucial insights into table operations, serving as a comprehensive guide for you navigating the intricacies of working with tables in Databend. It strings together essential table-related commands to provide a cohesive understanding of key considerations in table management.
6-
7-
## Table Creation Essentials
8-
9-
It is a good idea to to familiarize yourself with the following topics before proceeding to create a table.
10-
11-
### 1. Understanding Table Types
12-
13-
Databend supports two types of tables based on their Time Travel support:
14-
15-
- **General Tables (Default)**: These tables inherently support Time Travel, allowing you to trace and retrieve historical data. This feature is valuable for data analysis and auditing.
16-
17-
- **Transient Tables**: In contrast, transient tables do not support Time Travel. They are designed for scenarios where historical data tracking is not necessary. To create a transient table, you must explicitly specify the keyword TRANSIENT in the [CREATE TABLE](10-ddl-create-table.md) command. For more information, see [CREATE TRANSIENT TABLE](10-ddl-create-table.md#create-transient-table).
18-
19-
### 2. Selecting Table Storage
20-
21-
Databend defaults to storing table data in the location configured in the [databend-query.toml](https://github.com/databendlabs/databend/blob/main/scripts/distribution/configs/databend-query.toml) configuration file. Additionally, it provides the flexibility to store table data in a different bucket, deviating from the default setting. For more information, see [CREATE TABLE ... EXTERNAL_LOCATION](10-ddl-create-table.md#create-table--external_location).
22-
23-
### 3. Defining Table Structure
24-
25-
The primary method to define columns in a table is through the [CREATE TABLE](10-ddl-create-table.md#create-table) command, where you list your columns one by one. Please note that Computed Columns are supported as an Enterprise Edition feature in Databend. For more information, see [Computed Columns](10-ddl-create-table.md#computed-columns).
26-
27-
Databend also offers convenient methods for creating tables by copying column structures and even data from existing tables:
28-
29-
- [CREATE TABLE ... LIKE](10-ddl-create-table.md#create-table--like): Creates a table with the same column definitions as an existing one.
30-
- [CREATE TABLE ... AS](10-ddl-create-table.md#create-table--as): Creates a table and inserts data based on the results of a SELECT query.
31-
- [ATTACH TABLE](92-attach-table.md): Creates a table by associating it with an existing table.
32-
33-
### 4. Setting Cluster Key for Big Tables
34-
35-
[Cluster Key](../06-clusterkey/index.md) is designed to enhance query performance by physically organizing data in proximity. Databend recommends configuring cluster keys, especially for large tables encountering sluggish query performance. For the syntax to set a cluster key during table creation, see [SET CLUSTER KEY](../06-clusterkey/dml-set-cluster-key.md).
36-
37-
## Routine Table Maintenance
38-
39-
Once your table is created, you gain the foundation for organizing and managing your data effectively. With this structure in place, you can seamlessly execute various commands to enhance, modify, or extract information from your table. Whether it's adjusting column properties, fine-tuning configurations, or querying data, Databend provides a versatile set of tools to meet your evolving needs.
40-
41-
- [DESCRIBE TABLE](50-describe-table.md), [SHOW FIELDS](show-fields.md): Shows information about the columns in a given table.
42-
- [SHOW FULL COLUMNS](show-full-columns.md): Retrieves comprehensive details about the columns in a given table.
43-
- [SHOW CREATE TABLE](show-create-table.md): Shows the CREATE TABLE statement that creates the named table.
44-
- [SHOW DROP TABLES](show-drop-tables.md): Lists the dropped tables in the current or a specified database.
45-
- [SHOW TABLE STATUS](show-table-status.md): Shows the status of the tables in a database.
46-
- [SHOW TABLES](show-tables.md): Lists the tables in the current or a specified database.
47-
- [ALTER TABLE COLUMN](90-alter-table-column.md): Modifies the structure of a table by making changes to its columns.
48-
- [ALTER TABLE OPTION](90-alter-table-option.md): Modifies the Fuse engine [Options](../../../00-sql-reference/30-table-engines/00-fuse.md#options) of a table.
49-
- [RENAME TABLE](30-ddl-rename-table.md): Changes the name of a table.
50-
51-
## Table Deletion & Recovery Strategies
52-
53-
Databend provides a variety of commands for deleting a table or vacuuming the table data. The table below compares these commands, which may initially seem complex, outlining any associated recovery options for each operation.
54-
55-
| Command | Enterprise Edition? | Description | Recovery |
56-
| -------------------------------------------- | ------------------- | ------------------------------------------------------------------ | ---------------------------------------- |
57-
| [TRUNCATE TABLE](40-ddl-truncate-table.md) | No | Removes all data from a table while preserving the table's schema. | [FLASHBACK TABLE](70-flashback-table.md) |
58-
| [DROP TABLE](20-ddl-drop-table.md) | No | Deletes a table. | [UNDROP TABLE](21-ddl-undrop-table.md) |
59-
| [VACUUM TABLE](91-vacuum-table.md) | Yes | Permanently removes historical data files of a table. | Not applicable. |
60-
| [VACUUM DROP TABLE](91-vacuum-drop-table.md) | Yes | Permanently removes data files of dropped tables. | Not applicable. |
61-
62-
## Advanced Table Optimization Techniques
63-
64-
Tables in Databend might need optimizations over time to ensure efficient performance and storage utilization. In this case, the following commands can help you out:
5+
This page provides a comprehensive overview of table operations in Databend, organized by functionality for easy reference.
6+
7+
## Table Creation
8+
9+
| Command | Description |
10+
|---------|-------------|
11+
| [CREATE TABLE](10-ddl-create-table.md) | Creates a new table with specified columns and options |
12+
| [CREATE TABLE ... LIKE](10-ddl-create-table.md#create-table--like) | Creates a table with the same column definitions as an existing one |
13+
| [CREATE TABLE ... AS](10-ddl-create-table.md#create-table--as) | Creates a table and inserts data based on the results of a SELECT query |
14+
| [CREATE TRANSIENT TABLE](10-ddl-create-transient-table.md) | Creates a table without Time Travel support |
15+
| [CREATE EXTERNAL TABLE](10-ddl-create-table-external-location.md) | Creates a table with data stored in a specified external location |
16+
| [ATTACH TABLE](92-attach-table.md) | Creates a table by associating it with an existing table |
17+
18+
## Table Modification
19+
20+
| Command | Description |
21+
|---------|-------------|
22+
| [ALTER TABLE COLUMN](90-alter-table-column.md) | Modifies the structure of a table by making changes to its columns |
23+
| [ALTER TABLE CONNECTION](91-alter-table-connection.md) | Updates the connection settings for an external table |
24+
| [ALTER TABLE OPTION](90-alter-table-option.md) | Modifies the Fuse engine options of a table |
25+
| [ALTER TABLE COMMENT](90-alter-table-comment.md) | Updates the comment for a table |
26+
| [RENAME TABLE](30-ddl-rename-table.md) | Changes the name of a table |
27+
28+
## Table Information
29+
30+
| Command | Description |
31+
|---------|-------------|
32+
| [DESCRIBE TABLE](50-describe-table.md) / [SHOW FIELDS](show-fields.md) | Shows information about the columns in a given table |
33+
| [SHOW FULL COLUMNS](show-full-columns.md) | Retrieves comprehensive details about the columns in a given table |
34+
| [SHOW CREATE TABLE](show-create-table.md) | Shows the CREATE TABLE statement that creates the named table |
35+
| [SHOW TABLES](show-tables.md) | Lists the tables in the current or a specified database |
36+
| [SHOW TABLE STATUS](show-table-status.md) | Shows the status of the tables in a database |
37+
| [SHOW DROP TABLES](show-drop-tables.md) | Lists the dropped tables in the current or a specified database |
38+
39+
## Table Deletion & Recovery
40+
41+
| Command | Description | Recovery Option |
42+
|---------|-------------|----------------|
43+
| [TRUNCATE TABLE](40-ddl-truncate-table.md) | Removes all data from a table while preserving the table's schema | [FLASHBACK TABLE](70-flashback-table.md) |
44+
| [DROP TABLE](20-ddl-drop-table.md) | Deletes a table | [UNDROP TABLE](21-ddl-undrop-table.md) |
45+
| [VACUUM TABLE](91-vacuum-table.md) | Permanently removes historical data files of a table (Enterprise Edition) | Not recoverable |
46+
| [VACUUM DROP TABLE](91-vacuum-drop-table.md) | Permanently removes data files of dropped tables (Enterprise Edition) | Not recoverable |
47+
48+
## Table Optimization
49+
50+
| Command | Description |
51+
|---------|-------------|
52+
| [ANALYZE TABLE](80-analyze-table.md) | Calculates table statistics to improve query performance |
53+
| [OPTIMIZE TABLE](60-optimize-table.md) | Compacts or purges historical data to save storage space and enhance query performance |
54+
| [SET CLUSTER KEY](../06-clusterkey/dml-set-cluster-key.md) | Configures a cluster key to enhance query performance for large tables |
6555

6656
:::note
67-
Table Optimization is an advanced-level operation. Databend recommends carefully reading the links below and understanding the optimization process before proceeding to avoid potential data loss.
57+
Table optimization is an advanced operation. Please carefully read the documentation before proceeding to avoid potential data loss.
6858
:::
69-
70-
- [ANALYZE TABLE](80-analyze-table.md): Calculates table statistics.
71-
- [OPTIMIZE TABLE](60-optimize-table.md): Involves compacting or purging historical data to save storage space and enhance query performance.

0 commit comments

Comments
 (0)