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 |
DATABASE <database_name> |
SCHEMA |
SCHEMA <schema_name> |
<schema_name>
APPLICATION <application_name> |
APPLICATION PACKAGE <application_package_name> |
}
]
[ STARTS WITH '<name_string>' ]
[ LIMIT <rows> [ FROM '<name_string>' ] ]
Parameters¶
TERSE
Returns only a subset of the output columns:
created_on
name
kind
database_name
schema_name
LIKE 'pattern'
Optionally 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%' ...
. Default: No value (no filtering is applied to the output).
[ IN ... ]
Optionally specifies the scope of the command. Specify one of the following:
ACCOUNT
Returns records for the entire account.
DATABASE
, .DATABASE db_name
Returns records for the current database in use or for a specified database (
db_name
).If you specify
DATABASE
withoutdb_name
and no database is in use, the keyword has no effect on the output.SCHEMA
, .SCHEMA schema_name
, .schema_name
Returns records for the current schema in use or a specified schema (
schema_name
).SCHEMA
is optional if a database is in use or if you specify the fully qualifiedschema_name
(for example,db.schema
).If no database is in use, specifying
SCHEMA
has no effect on the output.
APPLICATION application_name
, .APPLICATION PACKAGE application_package_name
Returns records for the named Snowflake Native App or application package.
Default: Depends on whether the session currently has a database in use:
Database:
DATABASE
is the default (that is, the command returns the objects you have privileges to view in the database).No database:
ACCOUNT
is the default (that is, the command returns the objects you have privileges to view in your account).
STARTS WITH 'name_string'
Optionally filters the command output based on the 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 strings return different results:
... STARTS WITH 'B' ...
... STARTS WITH 'b' ...
. Default: No value (no filtering is applied to the output)
LIMIT rows [ FROM 'name_string' ]
Optionally limits the maximum number of rows returned, while also enabling “pagination” of the results. The actual number of rows returned might be less than the specified limit. For example, 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
For SHOW commands that support both the
FROM 'name_string'
andSTARTS WITH 'name_string'
clauses, you can combine both of these clauses 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 bySTARTS 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 exceed10000
. IfLIMIT 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:
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, for example |
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;