DROP TABLE (Transact-SQL)
Applies to:
SQL Server
Azure SQL Database
Azure SQL Managed Instance
Azure Synapse Analytics
Analytics Platform System (PDW)
Warehouse in Microsoft Fabric
Removes one or more table definitions and all data, indexes, triggers, constraints, and permission specifications for those tables. Any view or stored procedure that references the dropped table must be explicitly dropped by using DROP VIEW or DROP PROCEDURE. To report the dependencies on a table, use sys.dm_sql_referencing_entities.
Transact-SQL syntax conventions
Syntax
-- Syntax for SQL Server, Azure SQL Database, Warehouse in Microsoft Fabric
DROP TABLE [ IF EXISTS ] { database_name.schema_name.table_name | schema_name.table_name | table_name } [ ,...n ]
[ ; ]
-- Syntax for Azure Synapse Analytics and Parallel Data Warehouse
DROP TABLE { database_name.schema_name.table_name | schema_name.table_name | table_name }
[;]
Arguments
database_name
Is the name of the database in which the table was created.
Azure SQL Database supports the three-part name format database_name.schema_name.object_name
when database_name
is the current database or database_name
is tempdb
and object_name
starts with #
or ##
. Azure SQL Database doesn't support four-part names.
IF EXISTS
Applies to: SQL Server ( SQL Server 2016 (13.x) through current version).
Conditionally drops the table only if it already exists.
schema_name
Is the name of the schema to which the table belongs.
table_name
Is the name of the table to be removed.
Remarks
DROP TABLE
can't be used to drop a table that is referenced by a FOREIGN KEY
constraint. The referencing FOREIGN KEY
constraint or the referencing table must be dropped first.
Multiple tables can be dropped in the same DROP TABLE
statement. If both the referencing table in a FOREIGN KEY
constraint and the table with the referenced primary or unique key are being dropped in the same DROP TABLE
statement, the referencing table must be listed first.
When a table is dropped, rules or defaults on the table lose their binding, and any constraints or triggers associated with the table are automatically dropped. If you re-create a table, you must rebind the appropriate rules and defaults, re-create any triggers, and add all required constraints.
If you delete all rows in a table by using the DELETE
statement or use the TRUNCATE TABLE
statement, the table definition exists until it's dropped using DROP TABLE
.
If you drop a table that contains a varbinary(max)
column with the FILESTREAM
attribute, any data stored in the file system isn't removed.
When a ledger table is dropped, its dependent objects (the history table and the ledger view) are also dropped. A history table or a ledger view can't be dropped directly. The system enforces a soft-delete semantics when dropping ledger tables and its dependent objects – they aren't actually dropped, but instead they're marked as dropped in system catalog views and renamed. For more information, see Ledger considerations and limitations.
Important
DROP TABLE
and CREATE TABLE
shouldn't be executed on the same table in the same batch. Otherwise an unexpected error may occur.
In Fabric SQL database, dropping a table drops it both from the database and from Fabric OneLake. All mirrored data for the dropped table is removed.
Deferred deallocation
When a table is dropped, and the table or its indexes have 128 extents or more, the Database Engine defers the actual page deallocations, and their associated locks, until after the transaction commits. The table and indexes are dropped in two separate phases: logical and physical. In the logical phase, the existing allocation units are marked for deallocation and locked until the transaction commits. In the physical phase, a background process removes the pages marked for deallocation. This means that the space released by DROP TABLE
might not be available for new allocations immediately.
If accelerated database recovery is enabled, the separate logical and physical phases are used regardless of the number of extents.
Permissions
Requires the ALTER
permission on the schema to which the table belongs, CONTROL
permission on the table, or membership in the db_ddladmin
fixed database role.
If the statement drops a ledger table, the ALTER LEDGER
permission is required.
Examples
A. Dropping a table in the current database
The following example removes the ProductVendor1
table and its data and indexes from the current database.
DROP TABLE ProductVendor1;
B. Dropping a table in another database
The following example drops the SalesPerson2
table in the AdventureWorks2022
database. The example can be executed from any database on the server instance.
DROP TABLE AdventureWorks2022.dbo.SalesPerson2 ;
C. Dropping a temporary table
The following example creates a temporary table, tests for its existence, drops it, and tests again for its existence by attempting to execute a SELECT
statement, which fails. This example doesn't use the IF EXISTS
syntax which is available beginning with SQL Server 2016 (13.x).
CREATE TABLE #temptable (col1 int);
INSERT INTO #temptable
VALUES (10);
SELECT col1 FROM #temptable;
IF OBJECT_ID(N'tempdb..#temptable', N'U') isn't NULL
DROP TABLE #temptable;
SELECT col1 FROM #temptable;
D. Dropping a table using IF EXISTS
Applies to: SQL Server ( SQL Server 2016 (13.x) through current version).
The following example creates a table named T1
. Then the second statement drops the table. The third statement performs no action because the table is already dropped, however it doesn't cause an error.
CREATE TABLE T1 (Col1 int);
DROP TABLE T1;
DROP TABLE IF EXISTS T1;