SHOW SCHEMAS¶
Lists the schemas for which you have access privileges, including dropped schemas that are still within the Time Travel retention period and, therefore, can be undropped. The command can be used to list schemas for the current/specified database, or across your entire account.
The output returns schema metadata and properties, ordered lexicographically by database and schema name. This is important to note if you wish to filter the results using the provided filters.
- See also:
CREATE SCHEMA , ALTER SCHEMA , DESCRIBE SCHEMA , DROP SCHEMA , UNDROP SCHEMA
SCHEMATA view (Information Schema)
Syntax¶
SHOW [ TERSE ] SCHEMAS
[ HISTORY ]
[ LIKE '<pattern>' ]
[ IN { ACCOUNT | DATABASE [ <db_name> ] | APPLICATION <application_name> | APPLICATION PACKAGE <application_package_name> } ]
[ STARTS WITH '<name_string>' ]
[ LIMIT <rows> [ FROM '<name_string>' ] ]
[ WITH PRIVILEGES <object_privilege> [ , <object_privilege> [ , ... ] ] ]
Parameters¶
TERSE
Returns output containing only the following columns:
created_on
name
kind
database_name
schema_name
Note that
kind
andschema_name
always displayNULL
becausekind
is not applicable for schemas andschema_name
is redundant withname
.Default: No value (all columns are included in the output)
HISTORY
Includes dropped schemas that have not yet been purged (i.e. they are still within their respective Time Travel retention periods). If multiple versions of a dropped schema 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 schemas)
NULL
(for active schemas).
Default: No value (dropped schemas 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 ] | APPLICATION application_name | APPLICATION PACKAGE application_package_name }
Specifies the scope of the command, which determines whether the command lists records only for the current/specified database or across your entire account.
The
APPLICATION
andAPPLICATION PACKAGE
keywords are not required, but they specify the scope for the named Snowflake Native App.The
DATABASE
keyword is not required; you can set the scope by specifying only the database name. Likewise, the database name is not required if the session currently has a database in use.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'
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).
WITH PRIVILEGES object_privilege [ , object_privilege [ , ... ] ]
Optionally limits rows to objects for which the active role for the current user has been granted all of the specified privileges in the list on the object.
If a CREATE <object> privilege is included in the privileges list, the command excludes objects for which secondary roles have been granted privileges. This is because only the primary role has the authorization to create objects. For more information, see Enforcement model with primary role and secondary roles.
Usage notes¶
When you specify the scope to either
APPLICATION
or the database namedSNOWFLAKE
, theowner
column returnsSNOWFLAKE
as the owner for the schema namedLOCAL
. For example:SHOW SCHEMAS IN APPLICATION my_app; SHOW SCHEMAS IN DATABASE SNOWFLAKE;
The
owner
column returns:+-----+-------+-----+-----------+-----+ | ... | name | ... | owner | ... | +-----+-------+-----+-----------+-----+ | ... | LOCAL | ... | SNOWFLAKE | ... | +-----+-------+-----+-----------+-----+
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.
The
HISTORY
andWITH PRIVILEGES
parameters are mutually exclusive; they cannot both be used in the same statement.
Examples¶
Show all schemas in the current database, mytestdb
, that you have privileges to view:
SHOW SCHEMAS;
+---------------------------------+--------------------+------------+------------+---------------+--------+-----------------------------------------------------------+---------+----------------+-----------------+--------+
| created_on | name | is_default | is_current | database_name | owner | comment | options | retention_time | owner_role_type | budget |
|---------------------------------+--------------------+------------+------------+---------------+--------+-----------------------------------------------------------+---------+----------------+-----------------+--------+
| Fri, 13 May 2016 17:58:37 -0700 | INFORMATION_SCHEMA | N | N | MYTESTDB | | Views describing the contents of schemas in this database | | 1 | ROLE | NULL |
| Wed, 25 Feb 2015 16:16:54 -0800 | PUBLIC | N | Y | MYTESTDB | PUBLIC | | | 1 | ROLE | NULL |
+---------------------------------+--------------------+------------+------------+---------------+--------+-----------------------------------------------------------+---------+----------------+-----------------+--------+
Show all schemas in the current database, mytestdb
, that you have privileges to view, including dropped schemas (this example
builds on the DROP SCHEMA examples):
SHOW SCHEMAS HISTORY;
+---------------------------------+--------------------+------------+------------+---------------+--------+-----------------------------------------------------------+---------+----------------+---------------------------------+-----------------+----------+
| created_on | name | is_default | is_current | database_name | owner | comment | options | retention_time | dropped_on | owner_role_type | budget |
|---------------------------------+--------------------+------------+------------+---------------+--------+-----------------------------------------------------------+---------+----------------+---------------------------------+-----------------+----------+
| Fri, 13 May 2016 17:59:50 -0700 | INFORMATION_SCHEMA | N | N | MYTESTDB | | Views describing the contents of schemas in this database | | 1 | NULL | | NULL |
| Wed, 25 Feb 2015 16:16:54 -0800 | PUBLIC | N | Y | MYTESTDB | PUBLIC | | | 1 | NULL | ROLE | NULL |
| Tue, 17 Mar 2015 16:42:29 -0700 | MYSCHEMA | N | N | MYTESTDB | PUBLIC | | | 1 | Fri, 13 May 2016 17:25:32 -0700 | ROLE | MYBUDGET |
+---------------------------------+--------------------+------------+------------+---------------+--------+-----------------------------------------------------------+---------+----------------+---------------------------------+-----------------+----------+
Show all schemas in the current database that you have been granted the USAGE privilege on:
SHOW SCHEMAS WITH PRIVILEGES USAGE;
+-------------------------------+----------------+------------+------------+-----------------------------------------------------------+--------------+---------+---------+----------------+-----------------+--------+
| created_on | name | is_default | is_current | database_name | owner | comment | options | retention_time | owner_role_type | budget |
|-------------------------------+----------------+------------+------------+-----------------------------------------------------------+--------------+---------+---------+----------------+-----------------+--------|
| 2023-01-27 15:01:12.940 -0800 | PUBLIC | N | N | BOOKS_DB | DATA_ADMIN | | | 1 | ROLE | NULL |
| 2023-09-15 15:22:51.164 -0700 | PUBLIC | N | N | TEST_DB | ACCOUNTADMIN | | | 4 | ROLE | NULL |
| 2023-01-13 10:58:49.584 -0800 | ACCOUNT_USAGE | N | N | SNOWFLAKE | | | | 1 | | NULL |
+-------------------------------+----------------+------------+------------+-----------------------------------------------------------+--------------+---------+---------+----------------+-----------------+--------+