Categories:
Table, View, & Sequence DDL

SHOW TABLES

Lists the tables for which you have access privileges, including dropped tables that are still within the Time Travel retention period and, therefore, can be undropped. The command can be used to list tables for the current/specified database or schema, or across your entire account.

The output returns table metadata and properties, ordered lexicographically by database, schema, and 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 TABLE , DROP TABLE , UNDROP TABLE

TABLES View (Information Schema)

Syntax

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

Parameters

TERSE

Optionally returns only a subset of the output columns:

  • created_on
  • name
  • kind
  • database_name
  • schema_name

Default: No value (all columns are included in the output)

HISTORY

Optionally includes dropped tables that have not yet been purged (i.e. they are still within their respective Time Travel retention periods). If multiple versions of a dropped table exist, the output displays a row for each version. The output also includes an additional dropped_on column, which displays:

  • Date and timestamp (for dropped tables).
  • NULL (for active tables).

Default: No value (dropped tables are not included in the output)

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 ACCOUNT | [ DATABASE ] db_name | [ SCHEMA ] schema_name

Optionally 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:

DB in use:DATABASE is the default (i.e. the command returns the objects you have privileges to view in the database).
DB not in use:ACCOUNT is the default (i.e. 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 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. Note that the actual number of rows returned may 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 database 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

  • 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 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 | kind | comment | cluster_by | rows | bytes | owner | retention_time | dropped_on |
Column Description
created_on Date and time when the table was created.
name Name of the table.
database_name Database for the schema for the table.
schema_name Schema for the table.
kind Table type: TABLE (for permanent tables), TEMPORARY, or TRANSIENT.
comment Comment for the table.
cluster_by Columns defined as clustering keys for the table.
rows Number of rows in the table.
bytes Number of bytes that will be scanned if the entire table is scanned in a query. Note that this number may be different than the number of actual physical bytes (i.e. bytes stored on-disk) for the table.
owner Role that owns the table.
retention_time Number of days that modified and deleted data is retained for Time Travel.
dropped_on Date and time when the table was dropped; NULL if the table is active. This column is only displayed when the HISTORY keyword is specified for the command.

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

Note

For cloned tables and tables with deleted data, the bytes displayed for the table may be different than the number of physical bytes for the table:

  • A cloned table does not utilize additional data storage until new rows are added to the table or existing rows in the table are modified or deleted. If few or no changes have been made to the table, the number of bytes displayed is more than the actual physical bytes stored for the table.
  • Data deleted from a table is maintained in Snowflake until both the Time Travel retention period (default is 1 day) and Fail-safe period (7 days) for the data have passed. During these two periods, the number of bytes displayed is less than the actual physical bytes stored for the table.

For more detailed information about table size in bytes as it relates to cloning, Time Travel, and Fail-safe, see the TABLE_STORAGE_METRICS Information Schema view.

Examples

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

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

+-------------------------------+-----------+---------------+-----------------------+-------+---------+------------+------------+--------------+-------+----------------+
| created_on                    | name      | database_name | schema_name           | kind  | comment | cluster_by |       rows |        bytes | owner | retention_time |
|-------------------------------+-----------+---------------+-----------------------+-------+---------+------------+------------+--------------+-------+----------------|
| 2016-01-13 09:07:40.562 -0800 | LINEITEM  | TPCH          | PUBLIC                | TABLE |         |            |    6001215 |    165228544 |       |              1 |
+-------------------------------+-----------+---------------+-----------------------+-------+---------+------------+------------+--------------+-------+----------------+

Show all the tables, including dropped tables, that you have privileges to view in the tpch.public schema:

SHOW TABLES HISTORY IN tpch.public;

+-------------------------------+-----------+---------------+-----------------------+-------+---------+------------+------------+--------------+-------+----------------+---------------------------------+
| created_on                    | name      | database_name | schema_name           | kind  | comment | cluster_by |       rows |        bytes | owner | retention_time | dropped_on                      |
|-------------------------------+-----------+---------------+-----------------------+-------+---------+------------+------------+--------------+-------+----------------|---------------------------------|
| 2016-01-13 09:07:39.501 -0800 | CUSTOMER  | TPCH          | PUBLIC                | TABLE |         |            |     150000 |     10747904 |       |              1 | NULL                            |
| 2016-01-13 09:07:40.562 -0800 | LINEITEM  | TPCH          | PUBLIC                | TABLE |         |            |    6001215 |    165228544 |       |              1 | NULL                            |
| 2016-01-13 09:07:40.307 -0800 | ORDERS    | TPCH          | PUBLIC                | TABLE |         |            |    1500000 |     42303488 |       |              1 | NULL                            |
| 2016-01-13 09:07:39.708 -0800 | SUPPLIER  | TPCH          | PUBLIC                | TABLE |         |            |      10000 |       692224 |       |              1 | Fri, 13 May 2016 17:25:32 -0700 |
+-------------------------------+-----------+---------------+-----------------------+-------+---------+------------+------------+--------------+-------+----------------+---------------------------------+