The SHOW SUPER REGIONS statement lists the super regions for a multi-region cluster.
This feature is in preview and subject to change. To share feedback and/or issues, contact Support.
Synopsis
Required privileges
To view the super regions in a database, the user must have one of the following:
- Membership to the
adminrole for the cluster. - Either ownership or the
CREATEprivilege for the database.
Parameters
| Parameter | Description |
|---|---|
FROM DATABASE database_name |
Show all super regions for the specified database. |
Response
SHOW SUPER REGIONS FROM DATABASE returns the following fields for each super region:
| Field | Description |
|---|---|
database_name |
The database name this super region is associated with. |
super_region_name |
The name of a super region associated with the database. |
regions |
The list of database regions that make up the super region. |
Considerations
To use super regions, you must 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
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.
Examples
The examples in this section use the following setup.
Setup
Only a cluster region specified at node startup can be used as a database region.
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
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.
ridesALTER 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_codesALTER 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";usersALTER 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_historiesALTER 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";vehiclesALTER 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
View the super regions from a database
SHOW SUPER REGIONS FROM DATABASE returns the super regions for the specified database.
SHOW SUPER REGIONS FROM DATABASE movr;
database_name | super_region_name | regions
----------------+-------------------+----------------------
movr | usa | {us-east1,us-west1}
(1 row)
The preceding example shows the super region that was added in ADD SUPER REGION.