The ALTER DATABASE
statement applies a schema change to a database.
This schema change statement is registered as a job. You can view long-running jobs with SHOW JOBS
.
Required privileges
Refer to the respective subcommands.
Synopsis
Parameters
Parameter | Description |
---|---|
database_name |
The name of the database you want to change. |
Additional parameters are documented for the respective subcommands.
Subcommands
Subcommand | Description |
---|---|
ADD REGION |
Add a region to a multi-region database. (Enterprise-only.) |
ADD SUPER REGION |
Add a super region made up of a set of database regions such that data from regional tables will be stored in only those regions. (Enterprise-only.) |
ALTER LOCALITY |
New in v22.2: Persistently modify the configuration generated by the standard multi-region SQL abstractions on a per-region basis. For advanced users who want to customize their multi-region setup using Zone Config Extensions, a persistent, composable alternative to low-level zone configs. |
ALTER SUPER REGION |
Alter an existing super region to include a different set of regions. A super region is made up of a set of regions added with ADD REGION such that data from regional tables will be stored in only those regions. (Enterprise-only.) |
CONFIGURE ZONE |
Configure replication zones for a database. |
DROP REGION |
Drop a region from a multi-region database. (Enterprise-only.) |
DROP SECONDARY REGION |
Drop a secondary region from a multi-region database. (Enterprise-only.) |
DROP SUPER REGION |
Drop a super region made up of a set of database regions. (Enterprise-only.) |
OWNER TO |
Change the owner of a database. |
PLACEMENT |
Configure the replica placement policy for a multi-region database. |
RENAME TO |
Change the name of a database. |
RESET {session variable} |
Reset the session variable values for the database to the system defaults. This syntax is identical to ALTER ROLE ALL IN DATABASE ... RESET {session variable} . |
SET {session variable} |
Set the default session variable values for the database. This syntax is identical to ALTER ROLE ALL IN DATABASE ... SET {session variable} . |
SET PRIMARY REGION |
Set the primary region of a multi-region database. (Enterprise-only.) |
SET SECONDARY REGION |
Set the secondary region of a multi-region database for failover purposes. (Enterprise-only.) |
SURVIVE {ZONE,REGION} FAILURE |
Add a survival goal to a multi-region database. |
ADD REGION
ALTER DATABASE .. ADD REGION
adds a region to a multi-region database. While CockroachDB processes an index modification or changing a table to or from a REGIONAL BY ROW
table, attempting to drop a region from the database containing that REGIONAL BY ROW
table will produce an error. Similarly, while this statement is running, all index modifications and locality changes on REGIONAL BY ROW
tables will be blocked.
This is an enterprise-only feature. You can use free trial credits to try it out.
In order to add a region with ADD REGION
, you must first set a primary database region with SET PRIMARY REGION
, or at database creation. For an example showing how to add a primary region with ALTER DATABASE
, see Set the primary region.
For examples, see Manage regions.
Required privileges
To add a region to a database, the user must have one of the following:
- Membership to the
admin
role for the cluster. - Either ownership or the
CREATE
privilege for the database and allREGIONAL BY ROW
tables in the database.
Parameters
Parameter | Description |
---|---|
region_name |
The region being added to this database. Allowed values include any region present in SHOW REGIONS FROM CLUSTER . |
For usage, see Synopsis.
ADD SUPER REGION
ALTER DATABASE .. ADD SUPER REGION
adds a super region to a multi-region database.
This feature is in preview. This feature is subject to change. To share feedback and/or issues, contact Support.
This is an enterprise-only feature. You can use free trial credits to try it out.
To use super regions, keep the following considerations in mind:
- Your cluster must be a multi-region cluster.
- Super regions must be enabled.
- Super regions can only contain one or more database regions that have already been added with
ALTER DATABASE ... ADD REGION
. - Each database region can only belong to one super region. In other words, given two super regions A and B, the set of database regions in A must be disjoint from the set of database regions in B.
- You cannot drop a region that is part of a super region until you either alter the super region to remove it, or drop the super region altogether.
For examples, see Manage super regions.
Required privileges
To add a super region to a database, the user must have one of the following:
- Membership to the
admin
role for the cluster. - Either ownership or the
CREATE
privilege for the database.
Parameters
Parameter | Description |
---|---|
region_name |
The name of the super region being added to this database. |
region_name_list |
The super region consists of this set of database regions. |
For usage, see Synopsis.
ALTER LOCALITY
New in v22.2: ALTER DATABASE .. ALTER LOCALITY
provides a customization tool for advanced users to persistently modify the configuration generated by the standard multi-region SQL abstractions on a per-region basis.
The feature this statement enables is also known as Zone Config Extensions. For more information about how it works, and the benefits over using the low-level CONFIGURE ZONE
statement, see Zone Config Extensions.
For examples, see Use Zone Config Extensions.
Required privileges
The user must be a member of the admin
or owner roles, or have the CREATE
privilege on the database.
Parameters
Parameter | Description |
---|---|
GLOBAL |
Apply the Zone Configuration Extension to global tables. |
REGIONAL |
Apply the Zone Configuration Extension to all REGIONAL BY TABLE and REGIONAL BY ROW tables. |
REGIONAL IN |
Apply the Zone Configuration Extension to all REGIONAL BY TABLE IN {region} tables and all {region} partitions of REGIONAL BY ROW tables). |
variable |
The name of the replication zone variable to change for the schema objects in the specified region. |
value |
The value of the replication zone variable to change for the schema objects in the specified region. |
For usage, see Synopsis.
ALTER SUPER REGION
ALTER DATABASE .. ALTER SUPER REGION
alters an existing super region of a multi-region database.
This feature is in preview. This feature is subject to change. To share feedback and/or issues, contact Support.
This is an enterprise-only feature. You can use free trial credits to try it out.
To use super regions, keep the following considerations in mind:
- Your cluster must be a multi-region cluster.
- Super regions must be enabled.
- Super regions can only contain one or more database regions that have already been added with
ALTER DATABASE ... ADD REGION
. - Each database region can only belong to one super region. In other words, given two super regions A and B, the set of database regions in A must be disjoint from the set of database regions in B.
- You cannot drop a region that is part of a super region until you either alter the super region to remove it, or drop the super region altogether.
For examples, see Manage super regions.
Required privileges
To alter a database's super region, the user must have one of the following:
- Membership to the
admin
role for the cluster. - Either ownership or the
CREATE
privilege for the database.
Parameters
Parameter | Description |
---|---|
region_name |
The name of the super region being altered. |
region_name_list |
The altered super region will consist of this set of database regions. |
For usage, see Synopsis.
CONFIGURE ZONE
ALTER DATABASE ... CONFIGURE ZONE
is used to add, modify, reset, or remove replication zones for a database. To view details about existing replication zones, use SHOW ZONE CONFIGURATIONS
. For more information about replication zones, see Configure Replication Zones.
If you directly change a database's zone configuration with ALTER DATABASE ... CONFIGURE ZONE
, CockroachDB will block all ALTER DATABASE ... SET PRIMARY REGION
statements on the database.
You can use replication zones to control the number and location of replicas for specific sets of data, both when replicas are first added and when they are rebalanced to maintain cluster equilibrium.
For examples, see Configure replication zones.
Required privileges
The user must be a member of the admin
role or have been granted CREATE
or ZONECONFIG
privileges. To configure system
objects, the user must be a member of the admin
role.
Parameters
Parameter | Description |
---|---|
variable |
The name of the replication zone variable to change. |
value |
The value of the replication zone variable to change. |
DISCARD |
Remove a replication zone. |
For usage, see Synopsis.
DROP REGION
ALTER DATABASE .. DROP REGION
drops a region from a multi-region database. While CockroachDB processes an index modification or changing a table to or from a REGIONAL BY ROW
table, attempting to drop a region from the database containing that REGIONAL BY ROW
table will produce an error. Similarly, while this statement is running, all index modifications and locality changes on REGIONAL BY ROW
tables will be blocked.
This is an enterprise-only feature. You can use free trial credits to try it out.
You cannot drop a region from a multi-region database if:
- The region is set as the primary region, unless it is the last remaining region.
- The region is set as the secondary region. To drop the region, you must first unset the secondary region using
DROP SECONDARY REGION
. - The database uses the
REGION
survival goal and there are only three regions configured on the database.
For examples, see Manage regions.
Required privileges
To drop a region from a database, the user must have one of the following:
- Membership to the
admin
role for the cluster. - Membership to the owner role, or the
CREATE
privilege, for the database and allREGIONAL BY ROW
tables in the database.
Parameters
Parameter | Description |
---|---|
region_name |
The region being dropped from this database. Allowed values include any region present in SHOW REGIONS FROM DATABASE database_name .You can only drop the primary region from a multi-region database if it is the last remaining region. |
For usage, see Synopsis.
DROP SECONDARY REGION
New in v22.2: ALTER DATABASE .. DROP SECONDARY REGION
unsets the secondary region (if set) from a multi-region database.
This is an enterprise-only feature. You can use free trial credits to try it out.
The secondary region is used for failover purposes: if the primary region fails, the secondary region acts as the new primary region. For more information, see Secondary regions.
For examples, see Manage regions.
Required privileges
To unset a secondary region on a database, the user must have one of the following:
- Membership to the
admin
role for the cluster. - Membership to the owner role, or the
CREATE
privilege for the database.
DROP SUPER REGION
ALTER DATABASE .. DROP SUPER REGION
drops a super region from a multi-region database.
This feature is in preview. This feature is subject to change. To share feedback and/or issues, contact Support.
This is an enterprise-only feature. You can use free trial credits to try it out.
To use super regions, keep the following considerations in mind:
- Your cluster must be a multi-region cluster.
- Super regions must be enabled.
- Super regions can only contain one or more database regions that have already been added with
ALTER DATABASE ... ADD REGION
. - Each database region can only belong to one super region. In other words, given two super regions A and B, the set of database regions in A must be disjoint from the set of database regions in B.
- You cannot drop a region that is part of a super region until you either alter the super region to remove it, or drop the super region altogether.
For examples, see Manage super regions.
Required privileges
To drop a super region from a database, the user must have one of the following:
- Membership to the
admin
role for the cluster. - Either ownership or the
CREATE
privilege for the database.
Parameters
Parameter | Description |
---|---|
region_name |
The name of the super region being dropped from this database. |
For usage, see Synopsis.
OWNER TO
ALTER DATABASE ... OWNER TO
is used to change the owner of a database.
For examples, see Change database owner.
Required privileges
To change the owner of a database, the user must be an admin
user, or the current owner of the database and a member of the new owner role. The user must also have the CREATEDB
privilege.
Parameters
Parameter | Description |
---|---|
role_spec |
The role to set as the owner of the database. |
For usage, see Synopsis.
PLACEMENT
ALTER DATABASE ... PLACEMENT
is used to set the replica placement policy (DEFAULT
or RESTRICTED
) for a multi-region database's regional tables. Regional tables are those with REGIONAL BY ROW
or REGIONAL BY TABLE
localities.
ALTER DATABASE ... PLACEMENT RESTRICTED
constrains the voting and non-voting replica placement for the database's tables to the home regions associated with those tables. This is a way of opting out of non-voting replicas for regional tables to accomplish one or more of the following goals:
- Implement a data domiciling strategy.
- Reduce the amount of data stored on the cluster.
- Reduce the overhead of replicating data across a large number of regions (e.g., 10 or more) for databases with heavier write loads.
Note that ALTER DATABASE ... PLACEMENT RESTRICTED
does not allow you to opt out of placing non-voting replicas entirely. For example, GLOBAL
tables in the database will remain unaffected by this statement. GLOBAL
tables are designed to have replicas placed across all available cluster regions to ensure fast local reads.
For examples, see Set replica placement policy.
Required privileges
To use this statement, the user must have one of the following:
- Membership to the
admin
role for the cluster. - Ownership or the
CREATE
privilege for the database and all tables in the database.
Parameters
Parameter | Description |
---|---|
DEFAULT |
Set the replica placement policy for regional tables to DEFAULT . |
RESTRICTED |
Set the replica placement policy for regional tables to RESTRICTED . |
For usage, see Synopsis.
The replica placement policies work as follows:
DEFAULT
(Default): If the replica placement policy is set toDEFAULT
, CockroachDB will use its default replica placement settings, which mean that:- Data will be placed in as many regions as necessary to ensure your database survival goals are met.
- You can get fast stale reads from all database regions.
RESTRICTED
: If the replica placement policy is set toRESTRICTED
, CockroachDB will constrain replica placement to only those regions where the table has voting replicas (that is, replicas which participate in the Raft quorum). In practice, this means that voting replicas for the table will be constrained to the table's home region. Specifically, forREGIONAL BY TABLE
tables, it will only place replicas in the defined region (or the database's primary region); forREGIONAL BY ROW
tables, it will only place replicas for each underlying partition in the partition's specified region. Finally, note that:- Regional tables with this placement setting will no longer provide "fast stale reads" from other (non-home) regions, since fast stale reads rely on the presence of non-voting replicas.
- The
RESTRICTED
replica placement policy is only available for databases with theZONE
survival goal. - This setting does not affect how
GLOBAL
tables work; they will still place replicas in all database regions.
RENAME TO
ALTER DATABASE ... RENAME TO
changes the name of a database.
It is not possible to rename a database if the database is referenced by a view. For more details, see View Dependencies.
For examples, see Rename database.
Required privileges
To rename a database, the user must be a member of the admin
role or must have the CREATEDB
parameter set.
Parameters
Parameter | Description |
---|---|
database_new_name |
The name you want to use for the database. The new name must be unique and follow these identifier rules. You cannot rename a database if it is set as the current database or if sql_safe_updates = true . |
For usage, see Synopsis.
RESET {session variable}
ALTER DATABASE ... RESET {session variable}
resets a session variable for a database to its default value for the client session.
Required privileges
No privileges are required to reset a session setting.
Parameters
Parameter | Description |
---|---|
session_var |
The name of the session variable. |
For usage, see Synopsis.
Aliases
In CockroachDB, the following are aliases for ALTER DATABASE ... RESET {session variable}
:
SET {session variable}
ALTER DATABASE ... SET {session variable}
sets the default value of a session variable for all future sessions on the database. This command does not alter the session setting of the current session.
Required privileges
To set the role
session variable, the current user must be a member of the admin
role, or a member of the target role.
All other session variables do not require privileges to modify.
Parameters
Parameter | Description |
---|---|
variable |
The name of the session variable to set. The variable name is case-insensitive. |
value |
The value, or list of values, to assign to the session variable. |
For usage, see Synopsis.
Aliases
In CockroachDB, the following are aliases for ALTER DATABASE ... SET {session variable}
:
ALTER ROLE ALL IN DATABASE ... SET {session variable}
SET PRIMARY REGION
ALTER DATABASE .. SET PRIMARY REGION
sets the primary region of a multi-region database.
This is an enterprise-only feature. You can use free trial credits to try it out.
If a database's zone configuration has been directly set with an ALTER DATABASE ... CONFIGURE ZONE
statement, CockroachDB will block all ALTER DATABASE ... SET PRIMARY REGION
statements on the database.
To remove existing, manually-configured zones from a database (and unblock SET PRIMARY REGION
statements on the database), use an ALTER DATABASE ... CONFIGURE ZONE DISCARD
statement.
New in v22.2: Secondary regions allow you to define a database region that will be used for failover in the event your primary region goes down. For more information, see Secondary regions.
For examples, see Manage regions.
Required privileges
To add a primary region to a database with no existing regions, the user must have one of the following:
- Membership to the
admin
role for the cluster. - Membership to the owner role, or the
CREATE
privilege, for the database and all tables in the database.
To switch primary regions to a region that has already been added to a database, the user must have membership to the owner role for the database, or have the CREATE
privilege on the database.
Parameters
Parameter | Description |
---|---|
region_name |
The region to set as the database's primary region. Allowed values include any region present in SHOW REGIONS FROM CLUSTER . |
For usage, see Synopsis.
SET SECONDARY REGION
New in v22.2: ALTER DATABASE .. SET SECONDARY REGION
adds a secondary region to a multi-region database for failover purposes.
This is an enterprise-only feature. You can use free trial credits to try it out.
If the primary region fails, the secondary region becomes the new primary region. For more information, see Secondary regions.
In order to add a secondary region with ALTER DATABASE ... SET SECONDARY REGION
, you must first set a primary database region with SET PRIMARY REGION
, or when creating the database. For an example showing how to add a secondary region with ALTER DATABASE
, see Set the secondary region.
For examples, see Manage regions.
Required privileges
To add a secondary region to a database, the user must have one of the following:
- Membership to the
admin
role for the cluster. - Either ownership or the
CREATE
privilege for the database.
Parameters
Parameter | Description |
---|---|
region_name |
Usually, the region being set as the secondary region for this database. E.g., "ap-southeast-2" . Allowed values include any (non-primary) region present in SHOW REGIONS . |
For usage, see Synopsis.
SURVIVE {ZONE,REGION} FAILURE
ALTER DATABASE ... SURVIVE {ZONE,REGION} FAILURE
statement sets the survival goal for a multi-region database.
For examples, see Configure survival goals.
Required privileges
The user must be a member of the admin
or owner roles, or have the CREATE
privilege on the database.
Parameters
Parameter | Description |
---|---|
ZONE |
Set the survival goal to zone failure. |
REGION |
Set the survival goal to region failure. |
For usage, see Synopsis.
Examples
Manage regions
Setup
Only a cluster region specified at node startup can be used as a database region.
To follow along with the examples in this section, start a demo cluster with the --global
flag to simulate a multi-region cluster:
$ cockroach demo --global --nodes 9
To see the regions available to the databases in the cluster, use a SHOW REGIONS FROM CLUSTER
statement:
SHOW REGIONS FROM CLUSTER;
region | zones
---------------+----------
europe-west1 | {b,c,d}
us-east1 | {b,c,d}
us-west1 | {a,b,c}
(3 rows)
Set the primary region
Suppose you want to make the database movr
a multi-region database.
To add the first region to the database, or to set an already-added region as the primary region, use a SET PRIMARY REGION
statement:
ALTER DATABASE movr SET PRIMARY REGION "us-east1";
ALTER DATABASE PRIMARY REGION
Given a cluster with multiple regions, any databases in that cluster that have not yet had their primary regions set will have their replicas spread as broadly as possible for resiliency. When a primary region is added to one of these databases:
- All tables will be
REGIONAL BY TABLE
in the primary region by default. - This means that all such tables will have all of their voting replicas and leaseholders moved to the primary region. This process is known as rebalancing.
Add regions to a database
To add more regions to a database that already has at least one region:
ALTER DATABASE movr ADD region "us-west1";
ALTER DATABASE ADD REGION
ALTER DATABASE movr ADD region "europe-west1";
ALTER DATABASE ADD REGION
To view the regions associated with a multi-region database, use a SHOW REGIONS FROM DATABASE
statement:
SHOW REGIONS FROM DATABASE movr;
database | region | primary | secondary | zones
-----------+--------------+---------+-----------+----------
movr | us-east1 | t | f | {b,c,d}
movr | europe-west1 | f | f | {b,c,d}
movr | us-west1 | f | f | {a,b,c}
(3 rows)
Set the secondary region
To set an existing database region (that is not already the primary region) as the secondary region, use the following statement:
ALTER DATABASE movr SET SECONDARY REGION "us-west1";
ALTER DATABASE SET SECONDARY REGION
Now, the "us-west1"
region will act as the primary region if the original primary region fails.
Unset the secondary region
To unset an existing database region as the secondary region on a multi-region database, use the DROP SECONDARY REGION
statement:
ALTER DATABASE movr DROP SECONDARY REGION;
ALTER DATABASE DROP SECONDARY REGION
This statement does not drop the region from the database. To drop a region, use DROP REGION
.
Change the existing primary region
To change the primary region to another region in the database, use a SET PRIMARY REGION
statement.
ALTER DATABASE movr SET PRIMARY REGION "europe-west1";
ALTER DATABASE PRIMARY REGION
You can only change an existing primary region to a region that has already been added to the database. If you try to change the primary region to a region that is not already associated with a database, CockroachDB will return an error.
Drop a region from a database
To drop a region from a multi-region database, use a DROP REGION
statement.
ALTER DATABASE movr DROP REGION "us-east1";
ALTER DATABASE DROP REGION
You cannot drop a region from a multi-region database if:
- The region is set as the primary region, unless it is the last remaining region.
- The region is set as the secondary region. To drop the region, you must first unset the secondary region using
DROP SECONDARY REGION
. - The database uses the
REGION
survival goal and there are only three regions configured on the database.
Manage super regions
Setup
Only a cluster region specified at node startup can be used as a database region.
To follow along with the examples in this section, start a demo cluster with the --global
flag to simulate a multi-region cluster:
$ cockroach demo --global --nodes 9
To see the regions available to the databases in the cluster, use a SHOW REGIONS FROM CLUSTER
statement:
SHOW REGIONS FROM CLUSTER;
region | zones
---------------+----------
europe-west1 | {b,c,d}
us-east1 | {b,c,d}
us-west1 | {a,b,c}
(3 rows)
Set up MovR database regions
Execute the following statements. They will tell CockroachDB about the database's regions. This information is necessary so that CockroachDB can later move data around to optimize access to particular data from particular regions. For more information about how this works at a high level, see Database Regions.
ALTER DATABASE movr PRIMARY REGION "us-east1";
ALTER DATABASE movr ADD REGION "europe-west1";
ALTER DATABASE movr ADD REGION "us-west1";
Set up MovR global tables
Because the data in promo_codes
is not updated frequently (a.k.a., "read-mostly"), and needs to be available from any region, the right table locality is GLOBAL
.
ALTER TABLE promo_codes SET locality GLOBAL;
Next, alter the user_promo_codes
table to have a foreign key into the global promo_codes
table. This will enable fast reads of the promo_codes.code
column from any region in the cluster.
ALTER TABLE user_promo_codes
ADD CONSTRAINT user_promo_codes_code_fk
FOREIGN KEY (code)
REFERENCES promo_codes (code)
ON UPDATE CASCADE;
Set up MovR regional tables
All of the tables except promo_codes
contain rows which are partitioned by region, and updated very frequently. For these tables, the right table locality for optimizing access to their data is REGIONAL BY ROW
.
Apply this table locality to the remaining tables. These statements use a CASE
statement to put data for a given city in the right region and can take around 1 minute to complete for each table.
rides
ALTER TABLE rides ADD COLUMN region crdb_internal_region AS ( CASE WHEN city = 'amsterdam' THEN 'europe-west1' WHEN city = 'paris' THEN 'europe-west1' WHEN city = 'rome' THEN 'europe-west1' WHEN city = 'new york' THEN 'us-east1' WHEN city = 'boston' THEN 'us-east1' WHEN city = 'washington dc' THEN 'us-east1' WHEN city = 'san francisco' THEN 'us-west1' WHEN city = 'seattle' THEN 'us-west1' WHEN city = 'los angeles' THEN 'us-west1' END ) STORED; ALTER TABLE rides ALTER COLUMN REGION SET NOT NULL; ALTER TABLE rides SET LOCALITY REGIONAL BY ROW AS "region";
user_promo_codes
ALTER TABLE user_promo_codes ADD COLUMN region crdb_internal_region AS ( CASE WHEN city = 'amsterdam' THEN 'europe-west1' WHEN city = 'paris' THEN 'europe-west1' WHEN city = 'rome' THEN 'europe-west1' WHEN city = 'new york' THEN 'us-east1' WHEN city = 'boston' THEN 'us-east1' WHEN city = 'washington dc' THEN 'us-east1' WHEN city = 'san francisco' THEN 'us-west1' WHEN city = 'seattle' THEN 'us-west1' WHEN city = 'los angeles' THEN 'us-west1' END ) STORED; ALTER TABLE user_promo_codes ALTER COLUMN REGION SET NOT NULL; ALTER TABLE user_promo_codes SET LOCALITY REGIONAL BY ROW AS "region";
users
ALTER TABLE users ADD COLUMN region crdb_internal_region AS ( CASE WHEN city = 'amsterdam' THEN 'europe-west1' WHEN city = 'paris' THEN 'europe-west1' WHEN city = 'rome' THEN 'europe-west1' WHEN city = 'new york' THEN 'us-east1' WHEN city = 'boston' THEN 'us-east1' WHEN city = 'washington dc' THEN 'us-east1' WHEN city = 'san francisco' THEN 'us-west1' WHEN city = 'seattle' THEN 'us-west1' WHEN city = 'los angeles' THEN 'us-west1' END ) STORED; ALTER TABLE users ALTER COLUMN REGION SET NOT NULL; ALTER TABLE users SET LOCALITY REGIONAL BY ROW AS "region";
vehicle_location_histories
ALTER TABLE vehicle_location_histories ADD COLUMN region crdb_internal_region AS ( CASE WHEN city = 'amsterdam' THEN 'europe-west1' WHEN city = 'paris' THEN 'europe-west1' WHEN city = 'rome' THEN 'europe-west1' WHEN city = 'new york' THEN 'us-east1' WHEN city = 'boston' THEN 'us-east1' WHEN city = 'washington dc' THEN 'us-east1' WHEN city = 'san francisco' THEN 'us-west1' WHEN city = 'seattle' THEN 'us-west1' WHEN city = 'los angeles' THEN 'us-west1' END ) STORED; ALTER TABLE vehicle_location_histories ALTER COLUMN REGION SET NOT NULL; ALTER TABLE vehicle_location_histories SET LOCALITY REGIONAL BY ROW AS "region";
vehicles
ALTER TABLE vehicles ADD COLUMN region crdb_internal_region AS ( CASE WHEN city = 'amsterdam' THEN 'europe-west1' WHEN city = 'paris' THEN 'europe-west1' WHEN city = 'rome' THEN 'europe-west1' WHEN city = 'new york' THEN 'us-east1' WHEN city = 'boston' THEN 'us-east1' WHEN city = 'washington dc' THEN 'us-east1' WHEN city = 'san francisco' THEN 'us-west1' WHEN city = 'seattle' THEN 'us-west1' WHEN city = 'los angeles' THEN 'us-west1' END ) STORED; ALTER TABLE vehicles ALTER COLUMN REGION SET NOT NULL; ALTER TABLE vehicles SET LOCALITY REGIONAL BY ROW AS "region";
Enable super regions
To enable super regions, set the enable_super_regions
session setting to 'on'
:
SET enable_super_regions = 'on';
SET
You can also set the sql.defaults.super_regions.enabled
cluster setting to true
:
SET CLUSTER SETTING sql.defaults.super_regions.enabled = true;
SET CLUSTER SETTING
Add a super region to a database
To add a super region to a multi-region database, use the ALTER DATABASE ... ADD SUPER REGION
statement:
ALTER DATABASE movr ADD SUPER REGION "usa" VALUES "us-east1", "us-west1";
ALTER DATABASE ADD SUPER REGION
Alter a super region
This example assumes you have already added a "usa"
super region as shown in the example Add a super region to a database. If you wanted to drop the region us-west1
, you would first need to remove it from the super region.
To remove a region from a super region, use the ALTER DATABASE ... ALTER SUPER REGION
statement and list only the regions that should remain in the super region:
ALTER DATABASE movr ALTER SUPER REGION "usa" VALUES "us-east1";
ALTER DATABASE ALTER SUPER REGION
To add a region to a super region, alter the super region as shown above to be a list of regions that includes the existing and the new regions.
Allow user to modify a primary region that is part of a super region
By default, you may not change the primary region of a multi-region database when that region is part of a super region. This is a safety setting designed to prevent you from accidentally moving the data for a regional table that is meant to be stored in the super region out of that super region, which could break your data domiciling setup.
If you are sure about what you are doing, you can allow modifying the primary region by setting the alter_primary_region_super_region_override
session setting to 'on'
:
SET alter_primary_region_super_region_override = 'on';
SET
You can also accomplish this by setting the sql.defaults.alter_primary_region_super_region_override.enable
cluster setting to true
:
SET CLUSTER SETTING sql.defaults.alter_primary_region_super_region_override.enable = true;
SET CLUSTER SETTING
Drop a super region from a database
To drop a super region from a multi-region database, use a DROP SUPER REGION
statement:
ALTER DATABASE movr DROP SUPER REGION "usa";
ALTER DATABASE DROP SUPER REGION
Note that you cannot drop a region that is part of a super region until you either alter the super region to remove it, or drop the super region altogether.
For example, using the super region that was added in ADD SUPER REGION
:
ALTER DATABASE movr DROP REGION "us-west1";
ERROR: region us-west1 is part of super region usa
SQLSTATE: 2BP01
HINT: you must first drop super region usa before you can drop the region us-west1
Configure replication zones
Setup
The following examples use MovR, a fictional vehicle-sharing application, to demonstrate CockroachDB SQL statements. For more information about the MovR example application and dataset, see MovR: A Global Vehicle-sharing App.
To follow along, run cockroach demo
with the --geo-partitioned-replicas
flag. This command opens an interactive SQL shell to a temporary, 9-node in-memory cluster with the movr
database.
$ cockroach demo --geo-partitioned-replicas
Create a replication zone for a database
To control replication for a specific database, use the ALTER DATABASE ... CONFIGURE ZONE
statement to define the relevant values (other values will be inherited from the parent zone):
> ALTER DATABASE movr CONFIGURE ZONE USING num_replicas = 5, gc.ttlseconds = 100000;
CONFIGURE ZONE 1
> SHOW ZONE CONFIGURATION FROM DATABASE movr;
target | raw_config_sql
----------------+-------------------------------------------
DATABASE movr | ALTER DATABASE movr CONFIGURE ZONE USING
| range_min_bytes = 134217728,
| range_max_bytes = 536870912,
| gc.ttlseconds = 100000,
| num_replicas = 5,
| constraints = '[]',
| lease_preferences = '[]'
(1 row)
Edit a replication zone
ALTER DATABASE movr CONFIGURE ZONE USING range_min_bytes = 0, range_max_bytes = 90000, gc.ttlseconds = 89999, num_replicas = 4;
Remove a replication zone
When you discard a zone configuration, the objects it was applied to will then inherit a configuration from an object "the next level up"; e.g., if the object whose configuration is being discarded is a table, it will use its parent database's configuration.
You cannot DISCARD
any zone configurations on multi-region tables, indexes, or partitions if the multi-region abstractions created the zone configuration.
ALTER DATABASE movr CONFIGURE ZONE DISCARD;
Use Zone Config Extensions
The following examples show:
- How to override specific fields of a schema object's zone configs.
- How something like the Secondary regions multi-region abstraction could have been implemented using Zone Config Extensions. For this example, we will call it "Failover regions".
- How to reset a region's Zone Config Extensions.
- How to discard a region's Zone Config Extensions.
We strongly recommend using the multi-region abstractions over "rolling your own" using Zone Config Extensions. These examples are provided to show the flexibility of Zone Config Extensions.
Setup
The setup described in this section will be used in the examples below.
Start a cluster
Start a cockroach demo
cluster as follows:
cockroach demo --global --nodes=9
This gives us a (preloaded) MovR database on a cluster with the following regions, which can be viewed with SHOW REGIONS
:
SHOW REGIONS;
region | zones | database_names | primary_region_of | secondary_region_of
---------------+---------+----------------+-------------------+----------------------
europe-west1 | {b,c,d} | {} | {} | {}
us-east1 | {b,c,d} | {} | {} | {}
us-west1 | {a,b,c} | {} | {} | {}
(3 rows)
Make the database multi-region
Next, modify the database to use the multi-region abstractions as follows:
- Set the primary region using
SET PRIMARY REGION
. - Add the other two regions using
ADD REGION
.
ALTER DATABASE movr SET PRIMARY REGION "us-east1";
ALTER DATABASE movr ADD REGION "us-west1";
ALTER DATABASE movr ADD REGION "europe-west1";
Override specific fields of a schema object's zone configs
In this example we will configure a multi-region MovR database to update its lease_preferences
field.
Setting the primary region to us-east1
during the setup steps added us-east1
to lease_preferences
.
SHOW ZONE CONFIGURATION FROM DATABASE movr;
target | raw_config_sql
----------------+-------------------------------------------------------------------------------------------
DATABASE movr | ALTER DATABASE movr CONFIGURE ZONE USING
| range_min_bytes = 134217728,
| range_max_bytes = 536870912,
| gc.ttlseconds = 90000,
| num_replicas = 5,
| num_voters = 3,
| constraints = '{+region=europe-west1: 1, +region=us-east1: 1, +region=us-west1: 1}',
| voter_constraints = '[+region=us-east1]',
| lease_preferences = '[[+region=us-east1]]'
(1 row)
We will now use ALTER DATABASE ... ALTER LOCALITY
to overwrite the lease_preferences
field to add us-west1
to the list of regions:
ALTER DATABASE movr ALTER LOCALITY REGIONAL IN "us-east1" CONFIGURE ZONE USING lease_preferences = '[[+region=us-east1], [+region=us-west1]]';
To view the updated zone configs, enter the following statement:
SHOW ZONE CONFIGURATION FROM DATABASE movr;
target | raw_config_sql
----------------+-------------------------------------------------------------------------------------------
DATABASE movr | ALTER DATABASE movr CONFIGURE ZONE USING
| range_min_bytes = 134217728,
| range_max_bytes = 536870912,
| gc.ttlseconds = 90000,
| num_replicas = 5,
| num_voters = 3,
| constraints = '{+region=europe-west1: 1, +region=us-east1: 1, +region=us-west1: 1}',
| voter_constraints = '[+region=us-east1]',
| lease_preferences = '[[+region=us-east1], [+region=us-west1]]'
(1 row)
The lease_preferences
field is now updated to include us-west1
.
To remove the changes made in this example, reset the Zone Config Extensions.
Failover regions
In this example we will use Zone Config Extensions to configure a multi-region MovR database so that if the primary region fails, enough replicas will be found in another region (the "failover" region) to take over for the primary region. We will set the locality scope for this configuration to be REGIONAL IN
, which covers all REGIONAL BY TABLE IN {region}
tables and all {region}
partitions of REGIONAL BY ROW
tables.
This functionality is already provided by the built-in Secondary regions feature. It is used here to show the flexibility of Zone Config Extensions. We strongly recommend using the built-in multi-region features whenever possible.
Set the database to have a
REGION
survival goal usingALTER DATABASE ... SURVIVE REGION FAILURE
:ALTER DATABASE movr SURVIVE REGION FAILURE;
Apply the
REGIONAL BY ROW
locality to themovr.rides
table using the following statement:ALTER TABLE rides ADD COLUMN region crdb_internal_region AS ( CASE WHEN city = 'amsterdam' THEN 'europe-west1' WHEN city = 'paris' THEN 'europe-west1' WHEN city = 'rome' THEN 'europe-west1' WHEN city = 'new york' THEN 'us-east1' WHEN city = 'boston' THEN 'us-east1' WHEN city = 'washington dc' THEN 'us-east1' WHEN city = 'san francisco' THEN 'us-west1' WHEN city = 'seattle' THEN 'us-west1' WHEN city = 'los angeles' THEN 'us-west1' END ) STORED; ALTER TABLE rides ALTER COLUMN region SET NOT NULL; ALTER TABLE rides SET LOCALITY REGIONAL BY ROW AS "region";
View the zone configs for the
movr.rides
table usingSHOW ZONE CONFIGURATION
:SHOW ZONE CONFIGURATION FROM TABLE movr.rides;
target | raw_config_sql ----------------+------------------------------------------------------------------------------------------- DATABASE movr | ALTER DATABASE movr CONFIGURE ZONE USING | range_min_bytes = 134217728, | range_max_bytes = 536870912, | gc.ttlseconds = 90000, | num_replicas = 5, | num_voters = 5, | constraints = '{+region=europe-west1: 1, +region=us-east1: 1, +region=us-west1: 1}', | voter_constraints = '{+region=us-east1: 2}', | lease_preferences = '[[+region=us-east1]]' (1 row)
Remember that we configured
us-east1
to be our primary region during cluster setup. The output above confirms thatus-east1
is the primary region based on the values of thevoter_constraints
andlease_preferences
keys.Update the configuration to keep additional voting replicas and leaseholders in
us-west1
. We do this because we would like to configureus-west1
to be the failover region forus-east1
. The following SQL statement accomplishes this by configuringus-east1
to keep additional voting replicas and leaseholders inus-west1
. This means that ifus-east1
fails, it will fail over tous-west1
.ALTER DATABASE movr ALTER LOCALITY REGIONAL IN "us-east1" CONFIGURE ZONE USING voter_constraints = '{+region=us-east1: 2, +region=us-west1: 2}', lease_preferences = '[[+region=us-east1], [+region=us-west1]]';
View the zone configs for the
movr.rides
table usingSHOW ZONE CONFIGURATION
:SHOW ZONE CONFIGURATION FROM TABLE movr.rides;
target | raw_config_sql ----------------+------------------------------------------------------------------------------------------- DATABASE movr | ALTER DATABASE movr CONFIGURE ZONE USING | range_min_bytes = 134217728, | range_max_bytes = 536870912, | gc.ttlseconds = 90000, | num_replicas = 5, | num_voters = 5, | constraints = '{+region=europe-west1: 1, +region=us-east1: 1, +region=us-west1: 1}', | voter_constraints = '{+region=us-east1: 2, +region=us-west1: 2}', | lease_preferences = '[[+region=us-east1], [+region=us-west1]]' (1 row)
The following changes are shown: - There are now 2 voting replicas stored in
us-west1
. - There is now a preference that if leases cannot be placed inus-east1
, they should be placed inus-west1
.Both of these changes combine to ensure that if
us-east1
goes down, the cluster will still be able to operate until some mitigation is in place.
To remove the zone config changes made in this example, reset the Zone Config Extensions.
Reset a region's Zone Config Extensions
To reset the Zone Config Extension configuration applied to a region to the default settings, enter the following statement:
ALTER DATABASE movr ALTER LOCALITY CONFIGURE ZONE USING DEFAULT;
This will not reset any configuration created by the multi-region abstractions.
Discard a region's Zone Config Extensions
To discard the Zone Config Extension settings from a region, enter the following statement:
ALTER DATABASE movr ALTER LOCALITY CONFIGURE ZONE DISCARD;
When you discard a zone configuration, the objects it was applied to will then inherit a configuration from an object "the next level up"; e.g., if the object whose configuration is being discarded is a table, it will use its parent database's configuration.
However, this statement will not remove any configuration created by the multi-region abstractions.
Change database owner
Setup
The following examples use MovR, a fictional vehicle-sharing application, to demonstrate CockroachDB SQL statements. For more information about the MovR example application and dataset, see MovR: A Global Vehicle-sharing App.
To follow along, run cockroach demo
to start a temporary, in-memory cluster with the movr
dataset preloaded:
$ cockroach demo
Change a database's owner
Suppose that the current owner of the movr
database is root
and you want to change the owner to a new user named max
.
> ALTER DATABASE movr OWNER TO max;
To verify that the owner is now max
, query the pg_catalog.pg_database
and pg_catalog.pg_roles
tables:
> SELECT rolname FROM pg_catalog.pg_database d JOIN pg_catalog.pg_roles r ON d.datdba = r.oid WHERE datname = 'movr';
rolname
-----------
max
(1 row)
If the user running the command is not an admin user, they must own the database and be a member of the new owning role. They must also have the CREATEDB
privilege.
Set replica placement policy
Setup
To follow along with the examples below:
Start a demo cluster with the
--global
flag to simulate a multi-region cluster:cockroach demo --global --nodes 9
Set the demo cluster's database regions and table localities as described in Low Latency Reads and Writes in a Multi-Region Cluster (specifically, starting at Step 5. Execute multi-region SQL statements).
Enable the replica placement syntax with either the session variable or the cluster setting as shown below.
To use the session variable:
SET enable_multiregion_placement_policy = on;
To use the cluster setting:
SET CLUSTER SETTING sql.defaults.multiregion_placement_policy.enabled = on;
New in v22.2: Use ALTER ROLE ALL SET {sessionvar} = {val}
instead of the sql.defaults.*
cluster settings. This allows you to set a default value for all users for any session variable that applies during login, making the sql.defaults.*
cluster settings redundant.
Create a database with the replica placement policy set to restricted
If you know at database creation time that you'd like to set the database's replica placement policy to "restricted", you can do so in a CREATE DATABASE
statement as shown below:
CREATE DATABASE movr2 PRIMARY REGION "us-east1" REGIONS "us-west1", "europe-west1" PLACEMENT RESTRICTED;
CREATE DATABASE
Set the replica placement policy to RESTRICTED
When you set the database's placement policy to RESTRICTED
, you are saying that you want the underlying data to be restricted to the table or partition's home region.
ALTER DATABASE movr PLACEMENT RESTRICTED;
ALTER DATABASE PLACEMENT
Set the replica placement policy to DEFAULT
If previously you set the replica placement policy to RESTRICTED
, you can set it back to the default by issuing the following statement:
ALTER DATABASE movr PLACEMENT DEFAULT;
ALTER DATABASE PLACEMENT
Rename database
Rename a database
> CREATE DATABASE db1;
> SHOW DATABASES;
database_name
-----------------
db1
defaultdb
movr
postgres
system
(5 rows)
> ALTER DATABASE db1 RENAME TO db2;
> SHOW DATABASES;
database_name
-----------------
db2
defaultdb
movr
postgres
system
(5 rows)
Configure survival goals
Survive zone failures
To change the survival goal of a multi-region database to survive zone failures, use the following statement:
ALTER DATABASE {db} SURVIVE ZONE FAILURE;
ALTER DATABASE SURVIVE
Surviving zone failures is the default setting for multi-region databases.
For more information about the zone survival goal, see Surviving zone failures.
Survive region failures
To change the survival goal of a multi-region database to survive region failures, use the following statement:
ALTER DATABASE {db} SURVIVE REGION FAILURE;
ALTER DATABASE SURVIVE
If you try to change a database with less than 3 database regions to survive region failures, the following error will be signalled:
ERROR: at least 3 regions are required for surviving a region failure
SQLSTATE: 42602
HINT: you must add additional regions to the database using ALTER DATABASE mr ADD REGION <region_name>
For more information about the region survival goal, see Surviving region failures.