SHOW DYNAMIC TABLES¶
Lists the dynamic tables for which you have access privileges. The command can be used to list dynamic tables for the current/specified database or schema, or across your entire account.
- See also:
CREATE DYNAMIC TABLE, ALTER DYNAMIC TABLE, DESCRIBE DYNAMIC TABLE, DROP DYNAMIC TABLE, SHOW OBJECTS, TABLES view (Information Schema)
Syntax¶
SHOW DYNAMIC TABLES [ LIKE '<pattern>' ]
[ IN
{
ACCOUNT |
DATABASE |
DATABASE <db_name> |
SCHEMA |
SCHEMA <schema_name> |
<schema_name>
}
]
[ STARTS WITH '<name_string>' ]
[ LIMIT <rows> [ FROM '<name_string>' ] ]
Parameters¶
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.
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¶
To SHOW a dynamic table, you must be using a role that has MONITOR privilege on the table.
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 |
---|---|
|
Date and time when the dynamic table was created. |
|
Name of the dynamic table. |
|
|
|
Database in which the dynamic table is stored. |
|
Schema in which the dynamic table is stored. |
|
|
|
Number of rows in the table. |
|
Number of bytes that will be scanned if the entire dynamic 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. |
|
Role that owns the dynamic table. |
|
The maximum duration that the dynamic table’s content should lag behind real time. |
|
|
|
Explanation for why the refresh mode was chosen. If Snowflake chose |
|
Warehouse that provides the required resources to perform the incremental refreshes. |
|
Comment for the dynamic table. |
|
The text of the command that created this dynamic table (e.g. |
|
Whether auto-clustering is enabled on the dynamic table. Not currently supported for dynamic tables. |
|
Displays RUNNING for dynamic tables that are actively scheduling refreshes and SUSPENDED for suspended dynamic tables. |
|
Timestamp of last suspension. |
|
TRUE if the dynamic table has been cloned, else FALSE. |
|
TRUE if the dynamic table is a replica. else FALSE. |
|
Timestamp of the data in the base object(s) that is included in the dynamic table. |
|
The type of role that owns the object, for example |
Examples¶
Show all the dynamic tables with names that start with product_
in the mydb.myschema
schema:
SHOW DYNAMIC TABLES LIKE 'product_%' IN SCHEMA mydb.myschema;