SHOW EXTERNAL TABLES

Lists the external tables for which you have access privileges. The command can be used to list external tables for the current/specified database or schema, or across your entire account.

The output returns external table metadata and properties, ordered lexicographically by database, schema, and external table name (see Output in this topic for descriptions of the output columns). This is important to note if you wish to filter the results using the provided filters.

See also:

CREATE EXTERNAL TABLE , DROP EXTERNAL TABLE , ALTER EXTERNAL TABLE , DESCRIBE EXTERNAL TABLE

Syntax

SHOW [ TERSE ] EXTERNAL TABLES [ LIKE '<pattern>' ]
                               [ IN { ACCOUNT | DATABASE [ <db_name> ] | [ SCHEMA ] [ <schema_name> ] } ]
                               [ STARTS WITH '<name_string>' ]
                               [ LIMIT <rows> [ FROM '<name_string>' ] ]
Copy

Parameters

TERSE

Returns only a subset of the output columns:

  • created_on

  • name

  • kind

  • database_name

  • schema_name

LIKE 'pattern'

Filters the command output by object name. The filter uses case-insensitive pattern matching, with support for SQL wildcard characters (% and _).

For example, the following patterns return the same results:

... LIKE '%testing%' ...
... LIKE '%TESTING%' ...
IN ACCOUNT | [ DATABASE ] db_name | [ SCHEMA ] schema_name

Specifies the scope of the command, which determines whether the command lists records only for the current/specified database or schema, or across your entire account:

The DATABASE or SCHEMA keyword is not required; you can set the scope by specifying only the database or schema name. Likewise, the database or schema name is not required if the session currently has a database in use.

  • If DATABASE or SCHEMA is specified without a name and the session does not currently have a database in use, the parameter has no effect on the output.

  • If SCHEMA is specified with a name and the session does not currently have a database in use, the schema name must be fully qualified with the database name (e.g. testdb.testschema).

Default: Depends on whether the session currently has a database in use:

  • Database: DATABASE is the default (i.e. the command returns the objects you have privileges to view in the database).

  • No database: ACCOUNT is the default (i.e. the command returns the objects you have privileges to view in your account).

STARTS WITH 'name_string'

Filters the command output based on the string of characters that appear at the beginning of the object name. The string must be enclosed in single quotes and is case-sensitive. For example, the following return different results:

... STARTS WITH 'B' ...
... STARTS WITH 'b' ...
LIMIT rows [ FROM 'name_string' ]

Optionally limits the maximum number of rows returned, while also enabling “pagination” of the results. Note that the actual number of rows returned might be less than the specified limit (e.g. the number of existing objects is less than the specified limit).

The optional FROM 'name_string' subclause effectively serves as a “cursor” for the results. This enables fetching the specified number of rows following the first row whose object name matches the specified string:

  • The string must be enclosed in single quotes and is case-sensitive.

  • The string does not have to include the full object name; partial names are supported.

Default: No value (no limit is applied to the output)

Note

Both FROM 'name_string' and STARTS WITH 'name_string' can be combined in the same statement; however, both conditions must be met or they cancel out each other and no results are returned.

In addition, objects are returned in lexicographic order by name, so FROM 'name_string' only returns rows with a higher lexicographic value than the rows returned by STARTS WITH 'name_string'.

For example:

  • ... STARTS WITH 'A' LIMIT ... FROM 'B' would return no results.

  • ... STARTS WITH 'B' LIMIT ... FROM 'A' would return no results.

  • ... STARTS WITH 'A' LIMIT ... FROM 'AB' would return results (if any rows match the input strings).

Usage Notes

  • This command does not list external tables that have been dropped.

  • The command does not require a running warehouse to execute.

  • The value for LIMIT rows cannot exceed 10000. If LIMIT rows is omitted, the command results in an error if the result set is larger than 10K rows.

    To view results for which more than 10K records exist, either include LIMIT rows or query the corresponding view in the Snowflake Information Schema.

  • To post-process the output of this command, you can use the RESULT_SCAN function, which treats the output as a table that can be queried.

Output

The command output provides table properties and metadata in the following columns:

| created_on | name | database_name | schema_name | invalid | invalid_reason | owner | comment | stage | location | file_format_name | file_format_name | cloud | region | notification_channel | table_format | last_refresh_details |
Copy

Column

Description

created_on

Date and time when the external table was created.

name

Name of the external table.

database_name

Database for the schema for the external table.

schema_name

Schema for the external table.

invalid

TRUE if either the stage or file format referenced in the external table description is dropped.

invalid_reason

Reason why the external table is invalid, when the INVALID column shows a TRUE value.

owner

Role that owns the external table.

comment

Comment for the external table.

stage

Fully-qualified name of the stage referenced in the external table definition.

location

External stage and folder path in the external table definition. NULL for external tables in an imported share in a data consumer account.

file_format_name

Named file format in the external table definition. Does not display a file format specified in the stage definition.

file_format_type

File format type specified in the external table definition. Does not display a file format type specified in the stage definition.

cloud

Cloud in which the staged data files are located.

region

Region in which the staged data files are located.

notification_channel

Amazon Resource Name of the Amazon SQS queue for the external table.

last_refreshed_on

Timestamp that indicates when the metadata for the external table was last synchronized with the latest set of associated files in the external stage and path, either manually or automatically.

table_format

Table format of the staged files referenced by the external table. Possible values: DELTA, UNSPECIFIED.

last_refresh_details

Supports future functionality; currently NULL only.

owner_role_type

The type of role that owns the object, either ROLE or DATABASE_ROLE. Note that Snowflake returns NULL if you delete the object because there is no owner role for a deleted object.

For more information about the properties that can be specified for a external table, see CREATE EXTERNAL TABLE.

Examples

Show all the external tables whose name starts with line that you have privileges to view in the tpch.public schema:

SHOW EXTERNAL TABLES LIKE 'line%' IN tpch.public;
Copy