diff --git a/_includes/sidebar-data-v20.2.json b/_includes/sidebar-data-v20.2.json
index ac01f27d4b6..503d88f54df 100644
--- a/_includes/sidebar-data-v20.2.json
+++ b/_includes/sidebar-data-v20.2.json
@@ -1038,6 +1038,12 @@
"/${VERSION}/alter-role.html"
]
},
+ {
+ "title": "ALTER SCHEMA
",
+ "urls": [
+ "/${VERSION}/alter-schema.html"
+ ]
+ },
{
"title": "ALTER SEQUENCE
",
"urls": [
@@ -1150,6 +1156,12 @@
"title": "CREATE SCHEDULE FOR BACKUP
",
"urls": [
"/${VERSION}/create-schedule-for-backup.html"
+ ]
+ },
+ {
+ "title": "CREATE SCHEMA
",
+ "urls": [
+ "/${VERSION}/create-schema.html"
]
},
{
@@ -1240,6 +1252,12 @@
"title": "DROP SCHEDULES
",
"urls": [
"/${VERSION}/drop-schedules.html"
+ ]
+ },
+ {
+ "title": "DROP SCHEMA
",
+ "urls": [
+ "/${VERSION}/drop-schema.html"
]
},
{
diff --git a/v19.2/sql-feature-support.md b/v19.2/sql-feature-support.md
index 07049bd6824..7033c9aedae 100644
--- a/v19.2/sql-feature-support.md
+++ b/v19.2/sql-feature-support.md
@@ -162,6 +162,7 @@ table tr td:nth-child(2) {
Column families | ✓ | CockroachDB Extension | [Column Families documentation](column-families.html)
Interleaved tables | ✓ | CockroachDB Extension | [Interleaved Tables documentation](interleave-in-parent.html)
Information Schema | ✓ | Standard | [Information Schema documentation](information-schema.html)
+ User-defined Schemas | ✗ | Standard | Create, drop, and modify user-defined schemas.
Views | ✓ | Standard | [Views documentation](views.html)
Window functions | ✓ | Standard | [Window Functions documentation](window-functions.html)
Common Table Expressions | Partial | Common Extension | [Common Table Expressions documentation](common-table-expressions.html)
diff --git a/v19.2/sql-name-resolution.md b/v19.2/sql-name-resolution.md
index fc993b4d7ad..a63f67a474d 100644
--- a/v19.2/sql-name-resolution.md
+++ b/v19.2/sql-name-resolution.md
@@ -29,6 +29,10 @@ The schema name for all stored objects in any given database is always
objects because CockroachDB only supports a two-level storage
structure.
+{{site.data.alerts.callout_info}}
+CockroachDB versions < v20.2 do not support user-defined schemas.
+{{site.data.alerts.end}}
+
In addition to `public`, CockroachDB also supports a fixed set of
virtual schemas, available in every database, that provide ancillary, non-stored
data to client applications. For example,
diff --git a/v20.1/sql-feature-support.md b/v20.1/sql-feature-support.md
index 0a3073abfd0..7803438df80 100644
--- a/v20.1/sql-feature-support.md
+++ b/v20.1/sql-feature-support.md
@@ -163,6 +163,7 @@ table tr td:nth-child(2) {
Column families | ✓ | CockroachDB Extension | [Column Families documentation](column-families.html)
Interleaved tables | ✓ | CockroachDB Extension | [Interleaved Tables documentation](interleave-in-parent.html)
Information Schema | ✓ | Standard | [Information Schema documentation](information-schema.html)
+ User-defined Schemas | Planned | Standard | Create, drop, and modify user-defined schemas.
Views | ✓ | Standard | [Views documentation](views.html)
Window functions | ✓ | Standard | [Window Functions documentation](window-functions.html)
Common Table Expressions | Partial | Common Extension | [Common Table Expressions documentation](common-table-expressions.html)
diff --git a/v20.1/sql-name-resolution.md b/v20.1/sql-name-resolution.md
index fc993b4d7ad..4bf1278cb93 100644
--- a/v20.1/sql-name-resolution.md
+++ b/v20.1/sql-name-resolution.md
@@ -35,6 +35,10 @@ data to client applications. For example,
[`information_schema`](information-schema.html) is provided for
compatibility with the SQL standard.
+{{site.data.alerts.callout_info}}
+CockroachDB versions < v20.2 do not support user-defined schemas.
+{{site.data.alerts.end}}
+
The list of all databases can be obtained with [`SHOW
DATABASES`](show-databases.html). The list of all schemas for a given
database can be obtained with [`SHOW SCHEMAS`](show-schemas.html). The
diff --git a/v20.2/alter-schema.md b/v20.2/alter-schema.md
new file mode 100644
index 00000000000..08af2e423e6
--- /dev/null
+++ b/v20.2/alter-schema.md
@@ -0,0 +1,213 @@
+---
+title: ALTER SCHEMA
+summary: The ALTER SCHEMA statement modifies a user-defined schema in a database.
+toc: true
+---
+
+New in v20.2: The `ALTER SCHEMA` [statement](sql-statements.html) modifies a user-defined [schema](sql-name-resolution.html#logical-schemas-and-namespaces) in the current database. CockroachDB currently supports changing the name of the schema and the owner of the schema.
+
+## Syntax
+
+~~~
+ALTER SCHEMA ... RENAME TO
+ALTER SCHEMA ... OWNER TO { | CURRENT_USER | SESSION_USER }
+~~~
+
+### Parameters
+
+Parameter | Description
+----------|------------
+`RENAME TO ...` | Rename the schema. The new schema name must be unique within the current database and follow these [identifier rules](keywords-and-identifiers.html#identifiers).
+`OWNER TO ...` | Change the owner of the schema. You can specify the new owner by name or with the [`CURRENT_USER` or `SESSION_USER` keywords](functions-and-operators.html#special-syntax-forms).
+
+## Required privileges
+
+- To rename a schema, the user must be the owner of the schema.
+- To change the owner of a schema, the user must be the current owner of the schema and a member of the new owner [role](authorization.html#roles). The new owner role must also have the `CREATE` [privilege](authorization.html#assign-privileges) on the database to which the schema belongs.
+
+## Example
+
+### Rename a schema
+
+Suppose that you access the [SQL shell](cockroach-sql.html) as user `root`, and [create a new user](create-user.html) `max` and [a schema](create-schema.html) `org_one` with `max` as the owner:
+
+{% include copy-clipboard.html %}
+~~~ sql
+> CREATE USER max;
+~~~
+
+{% include copy-clipboard.html %}
+~~~ sql
+> CREATE SCHEMA org_one AUTHORIZATION max;
+~~~
+
+{% include copy-clipboard.html %}
+~~~ sql
+> SHOW SCHEMAS;
+~~~
+
+~~~
+ schema_name
+----------------------
+ crdb_internal
+ information_schema
+ org_one
+ pg_catalog
+ pg_extension
+ public
+(6 rows)
+~~~
+
+{% include copy-clipboard.html %}
+~~~ sql
+> SELECT
+ nspname, usename
+FROM
+ pg_catalog.pg_namespace
+ LEFT JOIN pg_catalog.pg_user ON pg_namespace.nspowner = pg_user.usesysid
+WHERE
+ nspname LIKE 'org_one';
+~~~
+
+~~~
+ nspname | usename
+----------+----------
+ org_one | max
+(1 row)
+~~~
+
+Now, suppose you want to rename the schema:
+
+{% include copy-clipboard.html %}
+~~~ sql
+> ALTER SCHEMA org_one RENAME TO org_two;
+~~~
+
+~~~
+ERROR: must be owner of schema "org_one"
+SQLSTATE: 42501
+~~~
+
+Because you are executing the `ALTER SCHEMA` command as a non-owner of the schema (i.e., `root`), CockroachDB returns an error.
+
+[Drop the schema](drop-schema.html) and create it again, this time with with `root` as the owner.
+
+{% include copy-clipboard.html %}
+~~~ sql
+> DROP SCHEMA org_one;
+~~~
+
+{% include copy-clipboard.html %}
+~~~ sql
+> CREATE SCHEMA org_one;
+~~~
+
+{% include copy-clipboard.html %}
+~~~ sql
+> SELECT
+ nspname, usename
+FROM
+ pg_catalog.pg_namespace
+ LEFT JOIN pg_catalog.pg_user ON pg_namespace.nspowner = pg_user.usesysid
+WHERE
+ nspname LIKE 'org_one';
+~~~
+
+~~~
+ nspname | usename
+----------+----------
+ org_one | root
+(1 row)
+~~~
+
+As its owner, you can rename the schema:
+
+{% include copy-clipboard.html %}
+~~~ sql
+> ALTER SCHEMA org_one RENAME TO org_two;
+~~~
+
+{% include copy-clipboard.html %}
+~~~ sql
+> SHOW SCHEMAS;
+~~~
+
+~~~
+ schema_name
+----------------------
+ crdb_internal
+ information_schema
+ org_two
+ pg_catalog
+ pg_extension
+ public
+(6 rows)
+~~~
+
+### Change a schema's owner
+
+Suppose that you access the [SQL shell](cockroach-sql.html) as user `root`, and [create a new schema](create-schema.html) named `org_one`:
+
+{% include copy-clipboard.html %}
+~~~ sql
+> CREATE SCHEMA org_one;
+~~~
+
+{% include copy-clipboard.html %}
+~~~ sql
+> SELECT
+ nspname, usename
+FROM
+ pg_catalog.pg_namespace
+ LEFT JOIN pg_catalog.pg_user ON pg_namespace.nspowner = pg_user.usesysid
+WHERE
+ nspname LIKE 'org_one';
+~~~
+
+~~~
+ nspname | usename
+----------+----------
+ org_one | root
+(1 row)
+~~~
+
+Now, suppose that you want to change the owner of the schema `org_one` to an existing user named `max`. To change the owner of a schema, the current owner must belong to the role of the new owner (in this case, `max`), and the new owner must have `CREATE` privileges on the database.
+
+{% include copy-clipboard.html %}
+~~~ sql
+> GRANT max TO root;
+~~~
+
+{% include copy-clipboard.html %}
+~~~ sql
+> GRANT CREATE ON DATABASE defaultdb TO max;
+~~~
+
+{% include copy-clipboard.html %}
+~~~ sql
+> ALTER SCHEMA org_one OWNER TO max;
+~~~
+
+{% include copy-clipboard.html %}
+~~~ sql
+> SELECT
+ nspname, usename
+FROM
+ pg_catalog.pg_namespace
+ LEFT JOIN pg_catalog.pg_user ON pg_namespace.nspowner = pg_user.usesysid
+WHERE
+ nspname LIKE 'org_one';
+~~~
+
+~~~
+ nspname | usename
+----------+----------
+ org_one | max
+(1 row)
+~~~
+
+## See also
+
+- [`CREATE SCHEMA`](create-schema.html)
+- [`SHOW SCHEMAS`](show-schemas.html)
+- [`DROP SCHEMA`](drop-schema.html)
diff --git a/v20.2/create-schema.md b/v20.2/create-schema.md
new file mode 100644
index 00000000000..e86098c5617
--- /dev/null
+++ b/v20.2/create-schema.md
@@ -0,0 +1,315 @@
+---
+title: CREATE SCHEMA
+summary: The CREATE SCHEMA statement creates a new user-defined schema.
+toc: true
+---
+
+New in v20.2: The `CREATE SCHEMA` [statement](sql-statements.html) creates a user-defined [schema](sql-name-resolution.html#logical-schemas-and-namespaces) in the current database.
+
+## Required privileges
+
+Only members of the `admin` role can create new schemas. By default, the `root` user belongs to the `admin` role.
+
+## Syntax
+
+~~~
+CREATE SCHEMA [IF NOT EXISTS] { | [] AUTHORIZATION {user_name | CURRENT_USER | SESSION_USER} }
+~~~
+
+### Parameters
+
+Parameter | Description
+----------|------------
+`IF NOT EXISTS` | Create a new schema only if a schema of the same name does not already exist within the current database. If one does exist, do not return an error.
+`schemaname` | The name of the schema to create, which must be unique within the current database and follow these [identifier rules](keywords-and-identifiers.html#identifiers).
+`AUTHORIZATION ...` | Optionally identify a user to be the owner of the schema. You can specify the owner by name, or with the [`CURRENT_USER` or `SESSION_USER` keywords](functions-and-operators.html#special-syntax-forms).
If a `CREATE SCHEMA` statement has an `AUTHORIZATION` clause, but no `schemaname`, the schema will be named after the specified owner of the schema. If a `CREATE SCHEMA` statement does not have an `AUTHORIZATION` clause, the user executing the statement will be named the owner.
+
+## Example
+
+### Create a schema
+
+{% include copy-clipboard.html %}
+~~~ sql
+> CREATE SCHEMA org_one;
+~~~
+
+{% include copy-clipboard.html %}
+~~~ sql
+> SHOW SCHEMAS;
+~~~
+
+~~~
+ schema_name
+----------------------
+ crdb_internal
+ information_schema
+ org_one
+ pg_catalog
+ pg_extension
+ public
+(6 rows)
+~~~
+
+By default, the user executing the `CREATE SCHEMA` statement is the owner of the schema. For example, suppose you created the schema as `root`. `root` would be the owner of the schema:
+
+{% include copy-clipboard.html %}
+~~~ sql
+> SELECT
+ nspname, usename
+FROM
+ pg_catalog.pg_namespace
+ LEFT JOIN pg_catalog.pg_user ON pg_namespace.nspowner = pg_user.usesysid
+WHERE
+ nspname LIKE 'org_one';
+~~~
+
+~~~
+ nspname | usename
+----------+----------
+ org_one | root
+(1 row)
+~~~
+
+### Create a schema if one does not exist
+
+{% include copy-clipboard.html %}
+~~~ sql
+> CREATE SCHEMA org_one;
+~~~
+
+~~~
+ERROR: schema "org_one" already exists
+~~~
+
+{% include copy-clipboard.html %}
+~~~ sql
+> CREATE SCHEMA IF NOT EXISTS org_one;
+~~~
+
+SQL does not generate an error, even though a new schema wasn't created.
+
+{% include copy-clipboard.html %}
+~~~ sql
+> SHOW SCHEMAS;
+~~~
+
+~~~
+ schema_name
+----------------------
+ crdb_internal
+ information_schema
+ org_one
+ pg_catalog
+ pg_extension
+ public
+(6 rows)
+~~~
+
+### Create two tables of the same name in different schemas
+
+You can create tables of the same name in the same database if they are in separate schemas.
+
+{% include copy-clipboard.html %}
+~~~ sql
+> CREATE SCHEMA IF NOT EXISTS org_one;
+~~~
+
+{% include copy-clipboard.html %}
+~~~ sql
+> CREATE SCHEMA IF NOT EXISTS org_two;
+~~~
+
+{% include copy-clipboard.html %}
+~~~ sql
+> SHOW SCHEMAS;
+~~~
+
+~~~
+ schema_name
+----------------------
+ crdb_internal
+ information_schema
+ org_one
+ org_two
+ pg_catalog
+ pg_extension
+ public
+(7 rows)
+~~~
+
+{% include copy-clipboard.html %}
+~~~ sql
+> CREATE TABLE org_one.employees (
+ id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
+ name STRING,
+ desk_no INT UNIQUE
+);
+~~~
+
+{% include copy-clipboard.html %}
+~~~ sql
+> CREATE TABLE org_two.employees (
+ id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
+ name STRING,
+ desk_no INT UNIQUE
+);
+~~~
+
+{% include copy-clipboard.html %}
+~~~ sql
+> SHOW TABLES;
+~~~
+
+~~~
+ schema_name | table_name | type | estimated_row_count
+--------------+------------+-------+----------------------
+ org_one | employees | table | 0
+ org_two | employees | table | 0
+(2 rows)
+~~~
+
+### Create a schema with authorization
+
+To specify the owner of a schema, add an `AUTHORIZATION` clause to the `CREATE SCHEMA` statement:
+
+{% include copy-clipboard.html %}
+~~~ sql
+> CREATE USER max WITH PASSWORD 'roach';
+~~~
+
+{% include copy-clipboard.html %}
+~~~ sql
+> CREATE SCHEMA org_two AUTHORIZATION max;
+~~~
+
+{% include copy-clipboard.html %}
+~~~ sql
+> SELECT
+ nspname, usename
+FROM
+ pg_catalog.pg_namespace
+ LEFT JOIN pg_catalog.pg_user ON pg_namespace.nspowner = pg_user.usesysid
+WHERE
+ nspname LIKE 'org_two';
+~~~
+
+~~~
+ nspname | usename
+----------+----------
+ org_two | max
+(1 row)
+~~~
+
+If no schema name is specified in a `CREATE SCHEMA` statement with an `AUTHORIZATION` clause, the schema will be named after the user specified:
+
+{% include copy-clipboard.html %}
+~~~ sql
+> CREATE SCHEMA AUTHORIZATION max;
+~~~
+
+{% include copy-clipboard.html %}
+~~~ sql
+> SELECT
+ nspname, usename
+FROM
+ pg_catalog.pg_namespace
+ LEFT JOIN pg_catalog.pg_user ON pg_namespace.nspowner = pg_user.usesysid
+WHERE
+ nspname LIKE 'max';
+~~~
+
+~~~
+ nspname | usename
+----------+----------
+ max | max
+(1 row)
+~~~
+
+When you [use a table without specifying a schema](sql-name-resolution.html#search-path), CockroachDB looks for the table in the `$user` schema (i.e., a schema named after the current user). If no schema exists with the name of the current user, the `public` schema is used.
+
+For example, suppose that you [grant the `admin` role](grant-roles.html) to the `max` user:
+
+{% include copy-clipboard.html %}
+~~~ sql
+> GRANT admin TO max;
+~~~
+
+Then, `max` [accesses the cluster](cockroach-sql.html) and creates two tables of the same name, in the same database, one in the `max` schema, and one in the `public` schema:
+
+{% include copy-clipboard.html %}
+~~~ shell
+$ cockroach sql --url 'postgres://max:roach@host:port/db?sslmode=require'
+~~~
+
+{% include copy-clipboard.html %}
+~~~ sql
+> CREATE TABLE max.accounts (
+ id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
+ name STRING,
+ balance DECIMAL
+);
+~~~
+
+{% include copy-clipboard.html %}
+~~~ sql
+> CREATE TABLE public.accounts (
+ id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
+ name STRING,
+ balance DECIMAL
+);
+~~~
+
+{% include copy-clipboard.html %}
+~~~ sql
+> SHOW TABLES;
+~~~
+
+~~~
+ schema_name | table_name | type | estimated_row_count
+--------------+------------+-------+----------------------
+ max | accounts | table | 0
+ public | accounts | table | 0
+(2 rows)
+~~~
+
+`max` then inserts some values into the `accounts` table, without specifying a schema:
+
+{% include copy-clipboard.html %}
+~~~ sql
+> INSERT INTO accounts (name, balance) VALUES ('checking', 1000), ('savings', 15000);
+~~~
+
+{% include copy-clipboard.html %}
+~~~ sql
+> SELECT * FROM accounts;
+~~~
+
+~~~
+ id | name | balance
+---------------------------------------+----------+----------
+ 7610607e-4928-44fb-9f4e-7ae6d6520666 | savings | 15000
+ 860b7891-cde4-4aff-a318-f928d47374bc | checking | 1000
+(2 rows)
+~~~
+
+Because `max` is the current user, all unqualified `accounts` table names resolve as `max.accounts`, and not `public.accounts`.
+
+{% include copy-clipboard.html %}
+~~~ sql
+> SELECT * FROM public.accounts;
+~~~
+
+~~~
+ id | name | balance
+-----+------+----------
+(0 rows)
+~~~
+
+## See also
+
+- [`SHOW SCHEMAS`](show-schemas.html)
+- [`SET SCHEMA`](set-vars.html)
+- [`DROP SCHEMA`](drop-schema.html)
+- [`ALTER SCHEMA`](alter-schema.html)
+- [Other SQL Statements](sql-statements.html)
+- [Online Schema Changes](online-schema-changes.html)
diff --git a/v20.2/detailed-sql-support.md b/v20.2/detailed-sql-support.md
index 73a55801978..8bef945c157 100644
--- a/v20.2/detailed-sql-support.md
+++ b/v20.2/detailed-sql-support.md
@@ -240,8 +240,8 @@ To understand the extent to which we support the standard SQL features, use the
| F302-01 | INTERSECT DISTINCT table operator | Yes |
| F302-02 | INTERSECT ALL table operator | Yes |
| F304 | EXCEPT ALL table operator | Yes |
-| F311 | Schema definition statement | No |
-| F311-01 | CREATE SCHEMA | No |
+| F311 | Schema definition statement | Yes |
+| F311-01 | CREATE SCHEMA | Yes |
| F311-02 | CREATE TABLE for persistent base tables | Yes |
| F311-03 | CREATE VIEW | Yes |
| F311-04 | CREATE VIEW: WITH CHECK OPTION | No |
diff --git a/v20.2/drop-schema.md b/v20.2/drop-schema.md
new file mode 100644
index 00000000000..b6952b6b7c6
--- /dev/null
+++ b/v20.2/drop-schema.md
@@ -0,0 +1,160 @@
+---
+title: DROP SCHEMA
+summary: The DROP SCHEMA statement removes a schema and all its objects from a CockroachDB cluster.
+toc: true
+---
+
+New in v20.2: The `DROP SCHEMA` [statement](sql-statements.html) removes a user-defined [schema](sql-name-resolution.html#logical-schemas-and-namespaces) from the current database.
+
+## Required privileges
+
+The user must have the `DROP` [privilege](authorization.html#assign-privileges) on the schema and on all tables in the schema. If the user is the owner of the schema, `DROP` privileges are not necessary.
+
+## Syntax
+
+~~~
+DROP SCHEMA [IF EXISTS] [, ...] [CASCADE | RESTRICT]
+~~~
+
+### Parameters
+
+Parameter | Description
+----------|------------
+`IF EXISTS` | Drop the schema if it exists. If it does not exist, do not return an error.
+`schema_name` | The name of the schema you want to drop from the current database.
+`CASCADE` | Drop all tables and views in the schema as well as all objects (such as [constraints](constraints.html) and [views](views.html)) that depend on those tables.
`CASCADE` does not list objects it drops, so should be used cautiously.
+`RESTRICT` | _(Default)_ Do not drop the schema if it contains any [tables](create-table.html) or [views](create-view.html).
+
+## Examples
+
+### Drop a schema
+
+{% include copy-clipboard.html %}
+~~~ sql
+> CREATE SCHEMA org_one;
+~~~
+
+{% include copy-clipboard.html %}
+~~~ sql
+> SHOW SCHEMAS;
+~~~
+
+~~~
+ schema_name
+----------------------
+ crdb_internal
+ information_schema
+ org_one
+ pg_catalog
+ pg_extension
+ public
+(6 rows)
+~~~
+
+{% include copy-clipboard.html %}
+~~~ sql
+> DROP SCHEMA org_one;
+~~~
+
+{% include copy-clipboard.html %}
+~~~ sql
+> SHOW SCHEMAS;
+~~~
+
+~~~
+ schema_name
+----------------------
+ crdb_internal
+ information_schema
+ pg_catalog
+ pg_extension
+ public
+(5 rows)
+~~~
+
+### Drop a schema with tables
+
+To drop a schema that contains tables, you need to use the `CASCADE` keyword.
+
+{% include copy-clipboard.html %}
+~~~ sql
+> CREATE SCHEMA org_two;
+~~~
+
+{% include copy-clipboard.html %}
+~~~ sql
+> SHOW SCHEMAS;
+~~~
+
+~~~
+ schema_name
+----------------------
+ crdb_internal
+ information_schema
+ org_two
+ pg_catalog
+ pg_extension
+ public
+(6 rows)
+~~~
+
+{% include copy-clipboard.html %}
+~~~ sql
+> CREATE TABLE org_two.users (
+ id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
+ city STRING,
+ name STRING,
+ address STRING
+);
+~~~
+
+{% include copy-clipboard.html %}
+~~~ sql
+> SHOW TABLES FROM org_two;
+~~~
+
+~~~
+ schema_name | table_name | type | estimated_row_count
+--------------+------------+-------+----------------------
+ org_two | users | table | 0
+(1 row)
+~~~
+
+{% include copy-clipboard.html %}
+~~~ sql
+> DROP SCHEMA org_two;
+~~~
+
+~~~
+ERROR: schema "org_two" is not empty and CASCADE was not specified
+SQLSTATE: 2BP01
+~~~
+
+{% include copy-clipboard.html %}
+~~~ sql
+> DROP SCHEMA org_two CASCADE;
+~~~
+
+{% include copy-clipboard.html %}
+~~~ sql
+> SHOW SCHEMAS;
+~~~
+
+~~~
+ schema_name
+----------------------
+ crdb_internal
+ information_schema
+ pg_catalog
+ pg_extension
+ public
+(5 rows)
+~~~
+
+## See also
+
+- [`CREATE SCHEMA`](create-schema.html)
+- [`SHOW SCHEMAS`](show-schemas.html)
+- [`SHOW JOBS`](show-jobs.html)
+- [Other SQL Statements](sql-statements.html)
+- [Online Schema Changes](online-schema-changes.html)
diff --git a/v20.2/show-schemas.md b/v20.2/show-schemas.md
index 2b79ca49aa6..33fddf8060b 100644
--- a/v20.2/show-schemas.md
+++ b/v20.2/show-schemas.md
@@ -24,9 +24,11 @@ Parameter | Description
## Example
+### Show schemas in the current database
+
{% include copy-clipboard.html %}
~~~ sql
-> SET DATABASE = bank;
+> CREATE SCHEMA org_one;
~~~
{% include copy-clipboard.html %}
@@ -35,20 +37,46 @@ Parameter | Description
~~~
~~~
-+--------------------+
-| schema_name |
-+--------------------+
-| crdb_internal |
-| information_schema |
-| pg_catalog |
-| public |
-+--------------------+
-(4 rows)
+ schema_name
+----------------------
+ crdb_internal
+ information_schema
+ org_one
+ pg_catalog
+ pg_extension
+ public
+(6 rows)
+~~~
+
+### Show ownership of schemas
+
+To show ownership of schemas, you need to query tables in the `pg_catalog` schema:
+
+{% include copy-clipboard.html %}
+~~~ sql
+> SELECT
+ nspname, usename
+FROM
+ pg_catalog.pg_namespace
+ LEFT JOIN pg_catalog.pg_user ON pg_namespace.nspowner = pg_user.usesysid;
+~~~
+
+~~~
+ nspname | usename
+---------------------+----------
+ crdb_internal | NULL
+ information_schema | NULL
+ pg_catalog | NULL
+ pg_extension | NULL
+ public | NULL
+ org_one | root
+(6 rows)
~~~
## See also
- [Logical Schemas and Namespaces](sql-name-resolution.html)
+- [`CREATE SCHEMA`](create-schema.html)
- [`SHOW DATABASES`](show-databases.html)
- [Information Schema](information-schema.html)
- [Other SQL Statements](sql-statements.html)
diff --git a/v20.2/sql-feature-support.md b/v20.2/sql-feature-support.md
index fef70bdc20d..e0cf2339c05 100644
--- a/v20.2/sql-feature-support.md
+++ b/v20.2/sql-feature-support.md
@@ -98,6 +98,9 @@ table tr td:nth-child(2) {
Index renames | ✓ | Standard | [`RENAME INDEX` documentation](rename-index.html)
Adding indexes | ✓ | Standard | [`CREATE INDEX` documentation](create-index.html)
Removing indexes | ✓ | Standard | [`DROP INDEX` documentation](drop-index.html)
+ Adding user-defined schemas | ✓ | Standard | New in v20.2: [`CREATE SCHEMA` documentation](create-schema.html)
+ Removing user-defined schemas | ✓ | Standard | New in v20.2: [`DROP SCHEMA` documentation](drop-schema.html)
+ Altering user-defined schemas | ✓ | Standard | New in v20.2: [`ALTER SCHEMA` documentation](create-schema.html)
### Statements
diff --git a/v20.2/sql-name-resolution.md b/v20.2/sql-name-resolution.md
index fc993b4d7ad..dcba3dd951b 100644
--- a/v20.2/sql-name-resolution.md
+++ b/v20.2/sql-name-resolution.md
@@ -8,12 +8,11 @@ A query can specify a table name without a database or schema name (e.g., `SELEC
This page details how CockroachDB performs **name resolution** to answer this question.
-
## Logical schemas and namespaces
A CockroachDB cluster can store multiple databases, and each database can store multiple tables/views/sequences. This **two-level structure for stored data** is commonly called the "logical schema" in relational database management systems.
-Meanwhile, CockroachDB aims to provide compatibility with PostgreSQL
+CockroachDB aims to provide compatibility with PostgreSQL
client applications and thus supports PostgreSQL's semantics for SQL
queries. To achieve this, CockroachDB supports a **three-level
structure for names**. This is called the "naming hierarchy".
@@ -24,22 +23,11 @@ In the naming hierarchy, the path to a stored object has three components:
- schema name
- object name
-The schema name for all stored objects in any given database is always
-`public`. There is only a single schema available for stored
-objects because CockroachDB only supports a two-level storage
-structure.
+The default schema name for all stored objects in any given database is `public`. In addition to `public`, CockroachDB supports a fixed set of virtual schemas, available in every database, that provide ancillary, non-stored data to client applications. For example, [`information_schema`](information-schema.html) is provided for compatibility with the SQL standard.
-In addition to `public`, CockroachDB also supports a fixed set of
-virtual schemas, available in every database, that provide ancillary, non-stored
-data to client applications. For example,
-[`information_schema`](information-schema.html) is provided for
-compatibility with the SQL standard.
+New in v20.2: CockroachDB also supports user-defined schemas with the [`CREATE SCHEMA` statement](create-schema.html).
-The list of all databases can be obtained with [`SHOW
-DATABASES`](show-databases.html). The list of all schemas for a given
-database can be obtained with [`SHOW SCHEMAS`](show-schemas.html). The
-list of all objects for a given schema can be obtained with other
-`SHOW` statements.
+The list of all databases can be obtained with [`SHOW DATABASES`](show-databases.html). The list of all schemas for a given database can be obtained with [`SHOW SCHEMAS`](show-schemas.html). The list of all objects for a given schema can be obtained with other `SHOW` statements.
## How name resolution works
@@ -49,13 +37,13 @@ Name resolution occurs separately to **look up existing objects** and to
The rules to look up an existing object are as follows:
1. If the name already fully specifies the database and schema, use that information.
-2. If the name has a single component prefix, try to find a schema with the prefix name in the [current database](#current-database). If that fails, try to find the object in the `public` schema of a database with the prefix name.
+2. If the name has a single-component prefix (e.g., a schema name), try to find a schema with the prefix name in the [current database](#current-database) and [current schema](#current-schema). If that fails, try to find the object in the `public` schema of a database with the prefix name.
3. If the name has no prefix, use the [search path](#search-path) with the [current database](#current-database).
Similarly, the rules to decide the full name of a new object are as follows:
1. If the name already fully specifies the database and schema, use that.
-2. If the name has a single component prefix, try to find a schema with that name. If no such schema exists, use the `public` schema in the database with the prefix name.
+2. If the name has a single-component prefix (e.g., a schema name), try to find a schema with that name. If no such schema exists, use the `public` schema in the database with the prefix name.
3. If the name has no prefix, use the [current schema](#current-schema) in the [current database](#current-database).
## Parameters for name resolution
@@ -73,15 +61,14 @@ database`](show-vars.html) and change it with [`SET database`](set-vars.html).
### Search path
-The search path is used when a name is unqualified (has no prefix). It lists the schemas where objects are looked up. Its first element is also the [current schema](#current-schema) where new objects are created.
+The search path is used when a name is unqualified (i.e., has no prefix). It lists the schemas where objects are looked up. Its first element is also the [current schema](#current-schema) where new objects are created.
- You can set the current search path with [`SET search_path`](set-vars.html) and inspected it with [`SHOW
search_path`](show-vars.html).
- You can inspect the list of valid schemas that can be listed in `search_path` with [`SHOW SCHEMAS`](show-schemas.html).
-- By default, the search path contains `public` and `pg_catalog`. For compatibility with PostgreSQL, `pg_catalog` is forced to be present in `search_path` at all times, even when not specified with
-`SET search_path`.
+- By default, the search path contains `$user`, `public`, and `pg_catalog`. For compatibility with PostgreSQL, `pg_catalog` is forced to be present in `search_path` at all times, even when not specified with `SET search_path`.
### Current schema
@@ -128,9 +115,7 @@ An unqualified name is a name with no prefix, that is, a simple identifier.
> SELECT * FROM mytable;
~~~
-This uses the search path over the current database. The search path
-is `public` by default, in the current database. The resolved name is
-`mydb.public.mytable`.
+This uses the search path over the current database. The search path is `$user` by default, in the current database. If a `$user` schema does not exist, the search path resolves to the `public` schema. In this case, there is no `$user` schema, and the resolved name is `mydb.public.mytable`.
{% include copy-clipboard.html %}
~~~ sql
@@ -177,9 +162,7 @@ For example:
This looks up `mytable` in the `public` schema of the current
database. If the current database is `mydb`, the lookup succeeds.
-For compatibility with CockroachDB 1.x, and to ease development in
-multi-database scenarios, CockroachDB also allows queries to specify
-a database name in a partially qualified name. For example:
+To ease development in multi-database scenarios, CockroachDB also allows queries to specify a database name in a partially qualified name. For example:
{% include copy-clipboard.html %}
~~~ sql
@@ -273,6 +256,7 @@ fully qualified name, as follows:
## See also
+- [`CREATE SCHEMA`](create-schema.html)
- [`SET`](set-vars.html)
- [`SHOW`](show-vars.html)
- [`SHOW DATABASES`](show-databases.html)
diff --git a/v20.2/sql-statements.md b/v20.2/sql-statements.md
index 5515fc940d7..9efaa6e7bff 100644
--- a/v20.2/sql-statements.md
+++ b/v20.2/sql-statements.md
@@ -40,6 +40,7 @@ Statement | Usage
[`ALTER PARTITION`](alter-partition.html) | Configure the replication zone for a partition. Note that [partitioning](partitioning.html) requires an [enterprise license](enterprise-licensing.html).
[`ALTER PRIMARY KEY`](alter-primary-key.html) | Change the [primary key](primary-key.html) of a table.
[`ALTER RANGE`](alter-range.html) | Configure the replication zone for a system range.
+[`ALTER SCHEMA`](alter-schema.html) | New in v20.2: Alter a user-defined schema.
[`ALTER SEQUENCE`](alter-sequence.html) | Apply a schema change to a sequence.
[`ALTER TABLE`](alter-table.html) | Apply a schema change to a table.
[`ALTER TYPE`](alter-type.html) | New in v20.2: Modify a user-defined, [enumerated data type](enum.html).
@@ -50,6 +51,7 @@ Statement | Usage
[`CONFIGURE ZONE`](configure-zone.html) | Add, modify, reset, or remove a [replication zone](configure-replication-zones.html) for a database, table, index, partition, or system range.
[`CREATE DATABASE`](create-database.html) | Create a new database.
[`CREATE INDEX`](create-index.html) | Create an index for a table.
+[`CREATE SCHEMA`](create-schema.html) | New in v20.2: Create a user-defined schema.
[`CREATE SEQUENCE`](create-sequence.html) | Create a new sequence.
[`CREATE TABLE`](create-table.html) | Create a new table in a database.
[`CREATE TABLE AS`](create-table-as.html) | Create a new table in a database using the results from a [selection query](selection-queries.html).
@@ -59,6 +61,7 @@ Statement | Usage
[`DROP CONSTRAINT`](drop-constraint.html) | Remove constraints from a column.
[`DROP DATABASE`](drop-database.html) | Remove a database and all its objects.
[`DROP INDEX`](drop-index.html) | Remove an index for a table.
+[`DROP SCHEMA`](drop-schema.html) | New in v20.2: Drop a user-defined schema.
[`DROP SEQUENCE`](drop-sequence.html) | Remove a sequence.
[`DROP TABLE`](drop-table.html) | Remove a table.
[`DROP TYPE`](drop-type.html) | New in v20.2: Remove a user-defined, [enumerated data type](enum.html).