sys.tables (Transact-SQL)

THIS TOPIC APPLIES TO: yesSQL Server (starting with 2008)yesAzure SQL DatabaseyesAzure SQL Data Warehouse yesParallel Data Warehouse

Returns a row for each user table in SQL Server.

Column name Data type Description
<inherited columns> For a list of columns that this view inherits, see sys.objects (Transact-SQL).
lob_data_space_id int A nonzero value is the ID of the data space (filegroup or partition scheme) that holds the large object binary (LOB) data for this table. Examples of LOB data types include varbinary(max), varchar(max), geography, or xml.

0 = The table does not LOB data.
filestream_data_space_id int Is the data space ID for a FILESTREAM filegroup or a partition scheme that consists of FILESTREAM filegroups.

To report the name of a FILESTREAM filegroup, execute the query SELECT FILEGROUPNAME (filestream\data_space_id) FROM sys.tables.

sys.tables can be joined to the following views on filestream_data_space_id = data_space_id.

- sys.filegroups

- sys.partition_schemes

- sys.indexes

- sys.allocation_units

- sys.fulltext_catalogs

- sys.data_spaces

- sys.destination_data_spaces

- sys.master_files

- sys.database_files

- backupfilegroup (join on filegroup_id)
max_column_id_used int Maximum column ID ever used by this table.
lock_on_bulk_load bit Table is locked on bulk load. For more information, see sp_tableoption (Transact-SQL).
uses_ansi_nulls bit Table was created with the SET ANSI_NULLS database option ON.
is_replicated bit 1 = Table is published using snapshot replication or transactional replication.
has_replication_filter bit 1 = Table has a replication filter.
is_merge_published bit 1 = Table is published using merge replication.
is_sync_tran_subscribed bit 1 = Table is subscribed using an immediate updating subscription.
has_unchecked_assembly_data bit 1 = Table contains persisted data that depends on an assembly whose definition changed during the last ALTER ASSEMBLY. Will be reset to 0 after the next successful DBCC CHECKDB or DBCC CHECKTABLE.
text_in_row_limit int The maximum bytes allowed for text in row.

0 = Text in row option is not set. For more information, see sp_tableoption (Transact-SQL).
large_value_types_out_of_row bit 1 = Large value types are stored out-of-row. For more information, see sp_tableoption (Transact-SQL).
is_tracked_by_cdc bit 1 = Table is enabled for change data capture. For more information, see sys.sp_cdc_enable_table (Transact-SQL).
lock_escalation tinyint The value of the LOCK_ESCALATION option for the table:

0 = TABLE

1 = DISABLE

2 = AUTO
lock_escalation_desc nvarchar(60) A text description of the lock_escalation option for the table. Possible values are: TABLE, AUTO, and DISABLE.
is_filetable bit Applies to: SQL Server 2012 through SQL Server 2016.

1 = Table is a FileTable.

For more information about FileTables, see FileTables (SQL Server).
durability tinyint Applies to: SQL Server 2014 through SQL Server 2016.

The following are possible values:

0 = SCHEMA_ONLY

1 = SCHEMA_AND_DATA

The value of 0 is the default value.
durability_desc nvarchar(60) Applies to: SQL Server 2014 through SQL Server 2016.

The following are the possible values:

SCHEMA_ONLY

SCHEMA_AND_DATA

The value of SCHEMA_AND_DATA indicates that the table is a durable, in-memory table. SCHEMA_AND_DATA is the default value for memory optimized tables. The value of SCHEMA_ONLY indicates that the table data will not be persisted upon restart of the database with memory optimized objects.
is_memory_optimized bit Applies to: SQL Server 2014 through SQL Server 2016.

The following are the possible values:

0 = not memory optimized.

1 = is memory optimized.

A value of 0 is the default value.

Memory optimized tables are in-memory user tables, the schema of which is persisted on disk similar to other user tables. Memory optimized tables can be accessed from natively compiled stored procedures.
temporal_type tinyint Applies to: SQL Server 2016 through SQL Server 2016.

The numeric value representing the type of table:

0 = NON_TEMPORAL_TABLE

1 = HISTORY_TABLE

2 = SYSTEM_VERSIONED_TEMPORAL_TABLE
temporal_type_desc nvarchar(60) Applies to: SQL Server 2016 through SQL Server 2016.

The text description of the type of table:

NON_TEMPORAL_TABLE

HISTORY_TABLE

SYSTEM_VERSIONED_TEMPORAL_TABLE
history_table_id int Applies to: SQL Server 2016 through SQL Server 2016.

When temporal_type IN (2, 4) returns object_id of the table that maintains historical data, otherwise returns NULL.
is_remote_data_archive_enabled bit Applies to: SQL Server 2016 through SQL Server 2016

Indicates whether the table is Stretch-enabled.

0 = The table is not Stretch-enabled.

1 = The table is Stretch-enabled.

For more info, see Stretch Database.
is_external bit Indicates table is an external table.

0 = The table is not an external table.

1 = The table is an external table.
history_retention_period int The numeric value representing duration of the temporal history retention period in units specified with history_retention_period_unit.
Applies to: SQL Database.
history_retention_period_unit int The numeric value representing type of temporal history retention period unit.

-1 :INFINITE

3: DAY

4: WEEK

5: MONTH

6: YEAR
Applies to: SQL Database.
history_retention_period_unit_desc nvarchar(10) The text description of type of temporal history retention period unit.

INFINITE

DAY

WEEK

MONTH

YEAR
Applies to: SQL Database.

Permissions

The visibility of the metadata in catalog views is limited to securables that a user either owns or on which the user has been granted some permission. For more information, see Metadata Visibility Configuration.

Examples

The following example returns all of the user tables that do not have a primary key.

SELECT SCHEMA_NAME(schema_id) AS schema_name  
    ,name AS table_name   
FROM sys.tables   
WHERE OBJECTPROPERTY(object_id,'TableHasPrimaryKey') = 0  
ORDER BY schema_name, table_name;  
GO  

The following example shows how related temporal data can be exposed.

||
|-|
|Applies to: SQL Server 2016 through SQL Server 2016.|

SELECT T1.object_id, T1.name as TemporalTableName, SCHEMA_NAME(T1.schema_id) AS TemporalTableSchema,  
T2.name as HistoryTableName, SCHEMA_NAME(T2.schema_id) AS HistoryTableSchema,  
T1.temporal_type_desc  
FROM sys.tables T1  
LEFT JOIN sys.tables T2   
ON T1.history_table_id = T2.object_id  
ORDER BY T1.temporal_type desc  

The following example shows how information on temporal history retention can be exposed.

||
|-|
|Applies to: SQL Database.|

SELECT DB.is_temporal_history_retention_enabled, SCHEMA_NAME(T1.schema_id) AS TemporalTableSchema, 
T1.name as TemporalTableName, SCHEMA_NAME(T2.schema_id) AS HistoryTableSchema, T2.name as HistoryTableName,
T1.history_retention_period, T1.history_retention_period_unit_desc
FROM sys.tables T1  
OUTER APPLY (select is_temporal_history_retention_enabled from sys.databases where name = DB_NAME()) DB
LEFT JOIN sys.tables T2   
ON T1.history_table_id = T2.object_id WHERE T1.temporal_type = 2 

See Also

Object Catalog Views (Transact-SQL)
Catalog Views (Transact-SQL)
DBCC CHECKDB (Transact-SQL)
DBCC CHECKTABLE (Transact-SQL)
Querying the SQL Server System Catalog FAQ
In-Memory OLTP (In-Memory Optimization)