EXTERNAL_TABLES View

This Information Schema view displays a row for each external table in the specified (or current) database.

See also:

COLUMNS View , VIEWS View

Columns

Column Name

Data Type

Description

TABLE_CATALOG

TEXT

Database that the table belongs to

TABLE_SCHEMA

TEXT

Schema that the table belongs to

TABLE_NAME

TEXT

Name of the table

TABLE_OWNER

TEXT

Name of the role that owns the table

CREATED

TIMESTAMP_LTZ

Creation time of the table

LAST_ALTERED

TIMESTAMP_LTZ

Date and time the object was last altered. See Usage Notes.

LAST_DDL

TIMESTAMP_LTZ

Timestamp of the last DDL operation performed on the table or view.

All supported table/view DDL operations update this field:

  • { CREATE | ALTER | DROP | UNDROP } TABLE

  • { CREATE | ALTER | DROP } VIEW

All ALTER TABLE operations update this field, including setting or unsetting a table parameter (for example, COMMENT, DATA_RETENTION_TIME, etc.) and changes to table columns (ADD / MODIFY / RENAME / DROP).

For more information, see the Usage Notes.

LAST_DDL_BY

TEXT

The current username for the user who executed the last DDL operation. If the user has been dropped, shows DROPPED_USER(<id>).

For dropped users, you can join the <id> with the USER_ID column in the USERS view.

AUTO_CLUSTERING_ON

BOOLEAN

Whether automatic clustering is enabled for the table

COMMENT

TEXT

Comment for this table

LOCATION

TEXT

External stage where the files containing data to be read are staged

FILE_FORMAT_NAME

TEXT

Named file format that describes the staged data files to scan when querying the external table

FILE_FORMAT_TYPE

TEXT

Format type of the staged data files to scan when querying the external table

Usage Notes

  • The view only displays objects for which the current role for the session has been granted access privileges. The view does not honor the MANAGE GRANTS privilege and consequently may show less information compared to a SHOW command when both are executed by a user who holds the MANAGE GRANTS privilege.

  • The view does not include external tables that have been dropped.

  • To view only external tables in your queries, filter using a WHERE clause, e.g.:

    ... WHERE table_schema != 'INFORMATION_SCHEMA'

  • The LAST_ALTERED column is updated when the following operations are performed on an object:

    • DDL operations.

    • DML operations (for tables only).

    • Background maintenance operations on metadata performed by Snowflake.

    For views and tables, use the LAST_DDL column for the last modification time for an object.

  • The value in the LAST_DDL column is updated as follows:

    • When a table or view is created, the LAST_DDL timestamp is the same as the CREATED timestamp.

    • When a table or view is dropped, the LAST_DDL timestamp is the same as the DELETED timestamp.

    • Last DDL data is not available for operations that occurred before the columns were added. The new DDL fields contain null until a DDL operation is executed.

    • For replicated databases, the LAST_DDL and LAST_DDL_BY fields are only updated for objects in the primary database. After failover, the LAST_DDL and LAST_DDL_BY fields are updated for DDL operations for the tables and views in the newly promoted primary database. These fields will remain unchanged for objects in the now secondary database.

    • For objects in secondary databases that are newly created during a refresh operation, these fields are null.

Examples

Retrieve the list of all external tables in all schemas in the mydatabase database:

SELECT table_name, last_altered FROM mydatabase.information_schema.external_tables;
Copy