- Installation
- Documentation
- Getting Started
- Connect
- Data Import
- Overview
- CSV Files
- JSON Files
- Multiple Files
- Parquet Files
- Partitioning
- Appender
- INSERT Statements
- Client APIs
- Overview
- C
- Overview
- Startup
- Configuration
- Query
- Data Chunks
- Vectors
- Values
- Types
- Prepared Statements
- Appender
- Table Functions
- Replacement Scans
- API Reference
- C++
- CLI
- Go
- Java
- Julia
- Node.js
- Python
- Overview
- Data Ingestion
- Conversion between DuckDB and Python
- DB API
- Relational API
- Function API
- Types API
- Expression API
- Spark API
- API Reference
- Known Python Issues
- R
- Rust
- Swift
- Wasm
- ADBC
- ODBC
- SQL
- Introduction
- Statements
- Overview
- ANALYZE
- ALTER TABLE
- ALTER VIEW
- ATTACH / DETACH
- CALL
- CHECKPOINT
- COMMENT ON
- COPY
- CREATE INDEX
- CREATE MACRO
- CREATE SCHEMA
- CREATE SECRET
- CREATE SEQUENCE
- CREATE TABLE
- CREATE VIEW
- CREATE TYPE
- DELETE
- DESCRIBE
- DROP
- EXPORT / IMPORT DATABASE
- INSERT
- PIVOT
- Profiling
- SELECT
- SET / RESET
- SET VARIABLE
- SUMMARIZE
- Transaction Management
- UNPIVOT
- UPDATE
- USE
- VACUUM
- LOAD / INSTALL
- Query Syntax
- SELECT
- FROM & JOIN
- WHERE
- GROUP BY
- GROUPING SETS
- HAVING
- ORDER BY
- LIMIT and OFFSET
- SAMPLE
- Unnesting
- WITH
- WINDOW
- QUALIFY
- VALUES
- FILTER
- Set Operations
- Prepared Statements
- Data Types
- Overview
- Array
- Bitstring
- Blob
- Boolean
- Date
- Enum
- Interval
- List
- Literal Types
- Map
- NULL Values
- Numeric
- Struct
- Text
- Time
- Timestamp
- Time Zones
- Union
- Typecasting
- Expressions
- Overview
- CASE Statement
- Casting
- Collations
- Comparisons
- IN Operator
- Logical Operators
- Star Expression
- Subqueries
- Functions
- Overview
- Aggregate Functions
- Array Functions
- Bitstring Functions
- Blob Functions
- Date Format Functions
- Date Functions
- Date Part Functions
- Enum Functions
- Interval Functions
- Lambda Functions
- List Functions
- Map Functions
- Nested Functions
- Numeric Functions
- Pattern Matching
- Regular Expressions
- Struct Functions
- Text Functions
- Time Functions
- Timestamp Functions
- Timestamp with Time Zone Functions
- Union Functions
- Utility Functions
- Window Functions
- Constraints
- Indexes
- Meta Queries
- DuckDB's SQL Dialect
- Samples
- Configuration
- Extensions
- Overview
- Core Extensions
- Community Extensions
- Working with Extensions
- Versioning of Extensions
- Arrow
- AutoComplete
- AWS
- Azure
- Delta
- Excel
- Full Text Search
- httpfs (HTTP and S3)
- Iceberg
- ICU
- inet
- jemalloc
- JSON
- MySQL
- PostgreSQL
- Spatial
- SQLite
- Substrait
- TPC-DS
- TPC-H
- VSS
- Guides
- Overview
- Data Viewers
- Database Integration
- File Formats
- Overview
- CSV Import
- CSV Export
- Directly Reading Files
- Excel Import
- Excel Export
- JSON Import
- JSON Export
- Parquet Import
- Parquet Export
- Querying Parquet Files
- Network & Cloud Storage
- Overview
- HTTP Parquet Import
- S3 Parquet Import
- S3 Parquet Export
- S3 Iceberg Import
- S3 Express One
- GCS Import
- Cloudflare R2 Import
- DuckDB over HTTPS / S3
- Meta Queries
- Describe Table
- EXPLAIN: Inspect Query Plans
- EXPLAIN ANALYZE: Profile Queries
- List Tables
- Summarize
- DuckDB Environment
- ODBC
- Performance
- Overview
- Import
- Schema
- Indexing
- Environment
- File Formats
- How to Tune Workloads
- My Workload Is Slow
- Benchmarks
- Python
- Installation
- Executing SQL
- Jupyter Notebooks
- SQL on Pandas
- Import from Pandas
- Export to Pandas
- Import from Numpy
- Export to Numpy
- SQL on Arrow
- Import from Arrow
- Export to Arrow
- Relational API on Pandas
- Multiple Python Threads
- Integration with Ibis
- Integration with Polars
- Using fsspec Filesystems
- SQL Editors
- SQL Features
- Snippets
- Glossary of Terms
- Browse Offline
- Operations Manual
- Overview
- Limits
- Non-Deterministic Behavior
- DuckDB's Footprint
- Securing DuckDB
- Development
- DuckDB Repositories
- Testing
- Overview
- sqllogictest Introduction
- Writing Tests
- Debugging
- Result Verification
- Persistent Testing
- Loops
- Multiple Connections
- Catch
- Profiling
- Release Calendar
- Building
- Overview
- Build Instructions
- Build Configuration
- Building Extensions
- Supported Platforms
- Troubleshooting
- Benchmark Suite
- Internals
- Sitemap
- Why DuckDB
- Media
- FAQ
- Code of Conduct
- Live Demo
The ALTER TABLE
statement changes the schema of an existing table in the catalog.
Examples
Add a new column with name k
to the table integers
, it will be filled with the default value NULL:
ALTER TABLE integers ADD COLUMN k INTEGER;
Add a new column with name l
to the table integers, it will be filled with the default value 10:
ALTER TABLE integers ADD COLUMN l INTEGER DEFAULT 10;
Drop the column k
from the table integers:
ALTER TABLE integers DROP k;
Change the type of the column i
to the type VARCHAR
using a standard cast:
ALTER TABLE integers ALTER i TYPE VARCHAR;
Change the type of the column i
to the type VARCHAR
, using the specified expression to convert the data for each row:
ALTER TABLE integers ALTER i SET DATA TYPE VARCHAR USING concat(i, '_', j);
Set the default value of a column:
ALTER TABLE integers ALTER COLUMN i SET DEFAULT 10;
Drop the default value of a column:
ALTER TABLE integers ALTER COLUMN i DROP DEFAULT;
Make a column not nullable:
ALTER TABLE t ALTER COLUMN x SET NOT NULL;
Drop the not null constraint:
ALTER TABLE t ALTER COLUMN x DROP NOT NULL;
Rename a table:
ALTER TABLE integers RENAME TO integers_old;
Rename a column of a table:
ALTER TABLE integers RENAME i TO j;
Syntax
ALTER TABLE
changes the schema of an existing table. All the changes made by ALTER TABLE
fully respect the transactional semantics, i.e., they will not be visible to other transactions until committed, and can be fully reverted through a rollback.
RENAME TABLE
Rename a table:
ALTER TABLE integers RENAME TO integers_old;
The RENAME TO
clause renames an entire table, changing its name in the schema. Note that any views that rely on the table are not automatically updated.
RENAME COLUMN
Rename a column of a table:
ALTER TABLE integers RENAME i TO j;
ALTER TABLE integers RENAME COLUMN j TO k;
The RENAME COLUMN
clause renames a single column within a table. Any constraints that rely on this name (e.g., CHECK
constraints) are automatically updated. However, note that any views that rely on this column name are not automatically updated.
ADD COLUMN
Add a new column with name k
to the table integers
, it will be filled with the default value NULL:
ALTER TABLE integers ADD COLUMN k INTEGER;
Add a new column with name l
to the table integers, it will be filled with the default value 10:
ALTER TABLE integers ADD COLUMN l INTEGER DEFAULT 10;
The ADD COLUMN
clause can be used to add a new column of a specified type to a table. The new column will be filled with the specified default value, or NULL
if none is specified.
DROP COLUMN
Drop the column k
from the table integers
:
ALTER TABLE integers DROP k;
The DROP COLUMN
clause can be used to remove a column from a table. Note that columns can only be removed if they do not have any indexes that rely on them. This includes any indexes created as part of a PRIMARY KEY
or UNIQUE
constraint. Columns that are part of multi-column check constraints cannot be dropped either.
ALTER TYPE
Change the type of the column i
to the type VARCHAR
using a standard cast:
ALTER TABLE integers ALTER i TYPE VARCHAR;
Change the type of the column i
to the type VARCHAR
, using the specified expression to convert the data for each row:
ALTER TABLE integers ALTER i SET DATA TYPE VARCHAR USING concat(i, '_', j);
The SET DATA TYPE
clause changes the type of a column in a table. Any data present in the column is converted according to the provided expression in the USING
clause, or, if the USING
clause is absent, cast to the new data type. Note that columns can only have their type changed if they do not have any indexes that rely on them and are not part of any CHECK
constraints.
SET
/ DROP DEFAULT
Set the default value of a column:
ALTER TABLE integers ALTER COLUMN i SET DEFAULT 10;
Drop the default value of a column:
ALTER TABLE integers ALTER COLUMN i DROP DEFAULT;
The SET/DROP DEFAULT
clause modifies the DEFAULT
value of an existing column. Note that this does not modify any existing data in the column. Dropping the default is equivalent to setting the default value to NULL.
Warning At the moment DuckDB will not allow you to alter a table if there are any dependencies. That means that if you have an index on a column you will first need to drop the index, alter the table, and then recreate the index. Otherwise, you will get a
Dependency Error
.
ADD
/ DROP CONSTRAINT
The
ADD CONSTRAINT
andDROP CONSTRAINT
clauses are not yet supported in DuckDB.