CREATE TABLE

Synopsis

Use the CREATE TABLE statement to create a new table in a database. It defines the table name, column names and types, primary key, and table properties.

Syntax

  1. create_table ::= CREATE [ TEMPORARY | TEMP ] TABLE [ IF NOT EXISTS ]
  2. table_name ( [ table_elem [ , ... ] ] )
  3. [ WITH ( { COLOCATED = { 'true' | 'false' }
  4. | storage_parameters } )
  5. | WITHOUT OIDS ] [ SPLIT ( INTO integer TABLETS ) ]
  6. table_elem ::= column_name data_type [ column_constraint [ ... ] ]
  7. | table_constraint
  8. column_constraint ::= [ CONSTRAINT constraint_name ]
  9. { NOT NULL
  10. | NULL
  11. | CHECK ( expression )
  12. | DEFAULT expression
  13. | UNIQUE index_parameters
  14. | PRIMARY KEY
  15. | references_clause }
  16. table_constraint ::= [ CONSTRAINT constraint_name ]
  17. { CHECK ( expression )
  18. | UNIQUE ( column_names ) index_parameters
  19. | PRIMARY KEY ( key_columns )
  20. | FOREIGN KEY ( column_names )
  21. references_clause }
  22. key_columns ::= hash_columns [ , range_columns ] | range_columns
  23. hash_columns ::= column_name [ HASH ] | ( column_name [ , ... ] ) HASH
  24. range_columns ::= { column_name { ASC | DESC } } [ , ... ]
  25. storage_parameters ::= storage_parameter [ , ... ]
  26. storage_parameter ::= param_name [ = param_value ]
  27. index_parameters ::= [ INCLUDE ( column_names ) ]
  28. [ WITH ( storage_parameters ) ]
  29. references_clause ::= REFERENCES table_name [ column_name [ , ... ] ]
  30. [ MATCH FULL | MATCH PARTIAL | MATCH SIMPLE ]
  31. [ ON DELETE key_action ]
  32. [ ON UPDATE key_action ]

create_table

CREATE TABLE - 图1

table_elem

CREATE TABLE - 图2

column_constraint

CREATE TABLE - 图3

table_constraint

CREATE TABLE - 图4

key_columns

CREATE TABLE - 图5

hash_columns

CREATE TABLE - 图6

range_columns

CREATE TABLE - 图7

storage_parameters

CREATE TABLE - 图8

storage_parameter

CREATE TABLE - 图9

index_parameters

CREATE TABLE - 图10

references_clause

CREATE TABLE - 图11

Semantics

Create a table with table_name. If qualified_name already exists in the specified database, an error will be raised unless the IF NOT EXISTS clause is used.

Primary key

Primary key can be defined in either column_constraint or table_constraint, but not in both.There are two types of primary key columns:

  • Hash primary key columns: The primary key may have zero or more leading hash-partitioned columns.By default, only the first column is treated as the hash-partition column. But this behavior can be modified by explicit use of the HASH annotation.

  • Range primary key columns: A table can have zero or more range primary key columns and it controls the top-level ordering of rows within a table (if there are no hash partition columns) or the ordering of rows among rows that share a common set of hash partitioned column values. By default, the range primary key columns are stored in ascending order. But this behavior can be controlled by explicit use of ASC or DESC.

For example, if the primary key specification is PRIMARY KEY ((a, b) HASH, c DESC) then columns a & b are used together to hash partition the table, and rows that share the same values for a and b are stored in descending order of their value for c.

If the primary key specification is PRIMARY KEY(a, b), then column a is used to hash partitionthe table and rows that share the same value for a are stored in ascending order of their valuefor b.

Foreign key

FOREIGN KEY and REFERENCES specifies that the set of columns can only contain values that are present in the referenced column(s) of the referenced table. It is used to enforce referential integrity of data.

Unique

This enforces that the set of columns specified in the UNIQUE constraint are unique in the table, that is, no two rows can have the same values for the set of columns specified in the UNIQUE constraint.

Check

This is used to enforce that data in the specified table meets the requirements specified in the CHECK clause.

Default

This clause is used to specify a default value for the column. If an INSERT statement does not specify a value for the column, then the default value is used. If no default is specified for a column, then the default is NULL.

Temporary or Temp

Using this qualifier will create a temporary table. Temporary tables are only visible in the current client session or transaction in which they are created and are automatically dropped at the end of the session or transaction. Any indexes created on temporary tables are temporary as well.

Split Into

The SPLIT INTO clause specifies the number of tablets that will be created for the table. This is useful for two data center (2DC) deployments. See example below: Create CDC table specifying number of tablets.

Colocated

NoteThis feature is currently in Beta.

For colocated databases, specify false to opt this table out of colocation. This means that the table won’t be stored on the same tablet as the rest of the tables for this database, but instead, will have its own set of tablets.Use this option for large tables that need to be scaled out. See colocated tables architecture for more details on when colocation is useful.

Note that colocated = true has no effect if the database that this table is part of is not colocated since colocation today is supported only at the database level.

Storage parameters

Storage parameters as defined by PostgreSQL are ignored and only present for compatibility with PostgreSQL.

Examples

Table with primary key

  1. yugabyte=# CREATE TABLE sample(k1 int,
  2. k2 int,
  3. v1 int,
  4. v2 text,
  5. PRIMARY KEY (k1, k2));

In this example, the first column k1 will be HASH, while second column k2 will be ASC.

  1. yugabyte=# \d sample
  2. Table "public.sample"
  3. Column | Type | Collation | Nullable | Default
  4. --------+---------+-----------+----------+---------
  5. k1 | integer | | not null |
  6. k2 | integer | | not null |
  7. v1 | integer | | |
  8. v2 | text | | |
  9. Indexes:
  10. "sample_pkey" PRIMARY KEY, lsm (k1 HASH, k2)

Table with range primary key

  1. yugabyte=# CREATE TABLE range(k1 int,
  2. k2 int,
  3. v1 int,
  4. v2 text,
  5. PRIMARY KEY (k1 ASC, k2 DESC));

Table with check constraint

  1. yugabyte=# CREATE TABLE student_grade(student_id int,
  2. class_id int,
  3. term_id int,
  4. grade int CHECK (grade >= 0 AND grade <= 10),
  5. PRIMARY KEY (student_id, class_id, term_id));

Table with default value

  1. yugabyte=# CREATE TABLE cars(id int PRIMARY KEY,
  2. brand text CHECK (brand in ('X', 'Y', 'Z')),
  3. model text NOT NULL,
  4. color text NOT NULL DEFAULT 'WHITE' CHECK (color in ('RED', 'WHITE', 'BLUE')));

Table with foreign key constraint

Define two tables with a foreign keys constraint.

  1. yugabyte=# CREATE TABLE products(id int PRIMARY KEY,
  2. descr text);
  3. yugabyte=# CREATE TABLE orders(id int PRIMARY KEY,
  4. pid int REFERENCES products(id) ON DELETE CASCADE,
  5. amount int);

Insert some rows.

  1. yugabyte=# SET SESSION CHARACTERISTICS AS TRANSACTION ISOLATION LEVEL SERIALIZABLE;
  2. yugabyte=# INSERT INTO products VALUES (1, 'Phone X'), (2, 'Tablet Z');
  3. yugabyte=# INSERT INTO orders VALUES (1, 1, 3), (2, 1, 3), (3, 2, 2);
  4. yugabyte=# SELECT o.id AS order_id, p.id as product_id, p.descr, o.amount FROM products p, orders o WHERE o.pid = p.id;
  1. order_id | product_id | descr | amount
  2. ----------+------------+----------+--------
  3. 1 | 1 | Phone X | 3
  4. 2 | 1 | Phone X | 3
  5. 3 | 2 | Tablet Z | 2
  6. (3 rows)

Inserting a row referencing a non-existent product is not allowed.

  1. yugabyte=# INSERT INTO orders VALUES (1, 3, 3);
  1. ERROR: insert or update on table "orders" violates foreign key constraint "orders_pid_fkey"
  2. DETAIL: Key (pid)=(3) is not present in table "products".

Deleting a product will cascade to all orders (as defined in the CREATE TABLE statement above).

  1. yugabyte=# DELETE from products where id = 1;
  2. yugabyte=# SELECT o.id AS order_id, p.id as product_id, p.descr, o.amount FROM products p, orders o WHERE o.pid = p.id;
  1. order_id | product_id | descr | amount
  2. ----------+------------+----------+--------
  3. 3 | 2 | Tablet Z | 2
  4. (1 row)

Table with unique constraint

  1. yugabyte=# CREATE TABLE translations(message_id int UNIQUE,
  2. message_txt text);

Create table specifying number of tablets

You can use the CREATE TABLE statement with the SPLIT INTO clause to specify the number of tablets for the table.This is useful for two data center (2DC) deployments that require identical number of tablets on both clusters.

  1. yugabyte=# CREATE TABLE tracking (id int PRIMARY KEY) SPLIT (INTO 10 TABLETS);

Opt table out of colocation

  1. yugabyte=# CREATE DATABASE company WITH colocated = true;
  2. yugabyte=# CREATE TABLE employee(id INT PRIMARY KEY, name TEXT) WITH (colocated = false);

In this example, database company is colocated and all tables other than the employee table are stored on a single tablet.

See also