From d5a9ad32cafb4dc5177a5815edf6f2d3285eff17 Mon Sep 17 00:00:00 2001 From: Eric Harmeling Date: Thu, 11 Jul 2019 13:31:14 -0700 Subject: [PATCH] MovR documentation updates SQL Statements examples: first commit (SHOW TABLES, CREATE TABLE, other markdown file dependencies) Added MovR overview doc; Removed drivers from two examples Added movr command to demo and workload More SQL statement examples (SHOW COLUMNS, SHOW TABLES, DROP TABLE) More SQL statement examples (INSERT) More SQL statement examples (DELETE, UPDATE, SELECT) Follow-up on rmloveland comments Follow-up on jseldess comments Removed MovR Learn CRDB SQL from movr-update feature branch --- _includes/sidebar-data-v19.2.json | 11 + _includes/v19.2/computed-columns/simple.md | 39 +- .../v19.2/faq/auto-generate-unique-ids.html | 78 +-- _includes/v19.2/misc/force-index-selection.md | 10 +- _includes/v19.2/performance/overview.md | 2 +- _includes/v19.2/sql/movr-start.md | 36 ++ .../v19.2/sql/movr-statements-no-data.md | 10 + _includes/v19.2/sql/movr-statements.md | 7 + v19.2/add-constraint.md | 2 +- v19.2/cockroach-demo.md | 1 + v19.2/cockroach-workload.md | 72 ++- v19.2/create-index.md | 51 +- v19.2/create-table.md | 467 +++++++++------- v19.2/delete.md | 106 ++-- v19.2/demo-geo-partitioning.md | 2 +- v19.2/drop-table.md | 133 +++-- v19.2/experimental-features.md | 2 +- v19.2/indexes.md | 2 +- v19.2/insert.md | 505 +++++++++--------- v19.2/movr.md | 93 ++++ v19.2/select-clause.md | 321 +++++------ v19.2/show-columns.md | 55 +- v19.2/show-index.md | 30 +- v19.2/show-tables.md | 130 +++-- v19.2/update.md | 376 +++++++------ v19.2/window-functions.md | 2 +- 26 files changed, 1481 insertions(+), 1062 deletions(-) create mode 100644 _includes/v19.2/sql/movr-start.md create mode 100644 _includes/v19.2/sql/movr-statements-no-data.md create mode 100644 _includes/v19.2/sql/movr-statements.md create mode 100644 v19.2/movr.md diff --git a/_includes/sidebar-data-v19.2.json b/_includes/sidebar-data-v19.2.json index 6e5561f51d5..8295bae1e8e 100644 --- a/_includes/sidebar-data-v19.2.json +++ b/_includes/sidebar-data-v19.2.json @@ -1831,6 +1831,17 @@ "urls": [ "/${VERSION}/diagnostics-reporting.html" ] + }, + { + "title": "Sample Applications", + "items": [ + { + "title": "MovR: Vehicle-Sharing App", + "urls": [ + "/${VERSION}/movr.html" + ] + } + ] } ] }, diff --git a/_includes/v19.2/computed-columns/simple.md b/_includes/v19.2/computed-columns/simple.md index d2bf9c16969..49045fc6cb7 100644 --- a/_includes/v19.2/computed-columns/simple.md +++ b/_includes/v19.2/computed-columns/simple.md @@ -2,36 +2,39 @@ In this example, let's create a simple table with a computed column: {% include copy-clipboard.html %} ~~~ sql -> CREATE TABLE names ( - id INT PRIMARY KEY, - first_name STRING, - last_name STRING, - full_name STRING AS (CONCAT(first_name, ' ', last_name)) STORED - ); +> CREATE TABLE users ( + id UUID PRIMARY KEY DEFAULT gen_random_uuid(), + city STRING, + first_name STRING, + last_name STRING, + full_name STRING AS (CONCAT(first_name, ' ', last_name)) STORED, + address STRING, + credit_card STRING, + dl STRING UNIQUE CHECK (LENGTH(dl) < 8) +); ~~~ Then, insert a few rows of data: {% include copy-clipboard.html %} ~~~ sql -> INSERT INTO names (id, first_name, last_name) VALUES - (1, 'Lola', 'McDog'), - (2, 'Carl', 'Kimball'), - (3, 'Ernie', 'Narayan'); +> INSERT INTO users (first_name, last_name) VALUES + ('Lola', 'McDog'), + ('Carl', 'Kimball'), + ('Ernie', 'Narayan'); ~~~ {% include copy-clipboard.html %} ~~~ sql -> SELECT * FROM names; +> SELECT * FROM users; ~~~ ~~~ -+----+------------+-------------+----------------+ -| id | first_name | last_name | full_name | -+----+------------+-------------+----------------+ -| 1 | Lola | McDog | Lola McDog | -| 2 | Carl | Kimball | Carl Kimball | -| 3 | Ernie | Narayan | Ernie Narayan | -+----+------------+-------------+----------------+ + id | city | first_name | last_name | full_name | address | credit_card | dl ++--------------------------------------+------+------------+-----------+---------------+---------+-------------+------+ + 5740da29-cc0c-47af-921c-b275d21d4c76 | NULL | Ernie | Narayan | Ernie Narayan | NULL | NULL | NULL + e7e0b748-9194-4d71-9343-cd65218848f0 | NULL | Lola | McDog | Lola McDog | NULL | NULL | NULL + f00e4715-8ca7-4d5a-8de5-ef1d5d8092f3 | NULL | Carl | Kimball | Carl Kimball | NULL | NULL | NULL +(3 rows) ~~~ The `full_name` column is computed from the `first_name` and `last_name` columns without the need to define a [view](views.html). diff --git a/_includes/v19.2/faq/auto-generate-unique-ids.html b/_includes/v19.2/faq/auto-generate-unique-ids.html index 419bc80ac65..d7ca0eaae30 100644 --- a/_includes/v19.2/faq/auto-generate-unique-ids.html +++ b/_includes/v19.2/faq/auto-generate-unique-ids.html @@ -2,27 +2,33 @@ {% include copy-clipboard.html %} ~~~ sql -> CREATE TABLE t1 (id UUID PRIMARY KEY DEFAULT gen_random_uuid(), name STRING); +> CREATE TABLE users ( + id UUID NOT NULL DEFAULT gen_random_uuid(), + city STRING NOT NULL, + name STRING NULL, + address STRING NULL, + credit_card STRING NULL, + CONSTRAINT "primary" PRIMARY KEY (city ASC, id ASC), + FAMILY "primary" (id, city, name, address, credit_card) +); ~~~ {% include copy-clipboard.html %} ~~~ sql -> INSERT INTO t1 (name) VALUES ('a'), ('b'), ('c'); +> INSERT INTO users (name, city) VALUES ('Petee', 'new york'), ('Eric', 'seattle'), ('Dan', 'seattle'); ~~~ {% include copy-clipboard.html %} ~~~ sql -> SELECT * FROM t1; +> SELECT * FROM users; ~~~ ~~~ -+--------------------------------------+------+ -| id | name | -+--------------------------------------+------+ -| 60853a85-681d-4620-9677-946bbfdc8fbc | c | -| 77c9bc2e-76a5-4ebc-80c3-7ad3159466a1 | b | -| bd3a56e1-c75e-476c-b221-0da9d74d66eb | a | -+--------------------------------------+------+ + id | city | name | address | credit_card ++--------------------------------------+----------+-------+---------+-------------+ + cf8ee4e2-cd74-449a-b6e6-a0fb2017baa4 | new york | Petee | NULL | NULL + 2382564e-702f-42d9-a139-b6df535ae00a | seattle | Eric | NULL | NULL + 7d27e40b-263a-4891-b29b-d59135e55650 | seattle | Dan | NULL | NULL (3 rows) ~~~ @@ -30,27 +36,33 @@ {% include copy-clipboard.html %} ~~~ sql -> CREATE TABLE t2 (id BYTES PRIMARY KEY DEFAULT uuid_v4(), name STRING); +> CREATE TABLE users2 ( + id BYTES DEFAULT uuid_v4(), + city STRING NOT NULL, + name STRING NULL, + address STRING NULL, + credit_card STRING NULL, + CONSTRAINT "primary" PRIMARY KEY (city ASC, id ASC), + FAMILY "primary" (id, city, name, address, credit_card) +); ~~~ {% include copy-clipboard.html %} ~~~ sql -> INSERT INTO t2 (name) VALUES ('a'), ('b'), ('c'); +> INSERT INTO users2 (name, city) VALUES ('Anna', 'new york'), ('Jonah', 'seattle'), ('Terry', 'chicago'); ~~~ {% include copy-clipboard.html %} ~~~ sql -> SELECT * FROM t2; +> SELECT * FROM users; ~~~ ~~~ -+---------------------------------------------------+------+ -| id | name | -+---------------------------------------------------+------+ -| "\x9b\x10\xdc\x11\x9a\x9cGB\xbd\x8d\t\x8c\xf6@vP" | a | -| "\xd9s\xd7\x13\n_L*\xb0\x87c\xb6d\xe1\xd8@" | c | -| "\uac74\x1dd@B\x97\xac\x04N&\x9eBg\x86" | b | -+---------------------------------------------------+------+ + id | city | name | address | credit_card ++------------------------------------------------+----------+-------+---------+-------------+ + 4\244\277\323/\261M\007\213\275*\0060\346\025z | chicago | Terry | NULL | NULL + \273*t=u.F\010\274f/}\313\332\373a | new york | Anna | NULL | NULL + \004\\\364nP\024L)\252\364\222r$\274O0 | seattle | Jonah | NULL | NULL (3 rows) ~~~ @@ -60,27 +72,33 @@ {% include copy-clipboard.html %} ~~~ sql -> CREATE TABLE t3 (id INT PRIMARY KEY DEFAULT unique_rowid(), name STRING); +> CREATE TABLE users3 ( + id INT DEFAULT unique_rowid(), + city STRING NOT NULL, + name STRING NULL, + address STRING NULL, + credit_card STRING NULL, + CONSTRAINT "primary" PRIMARY KEY (city ASC, id ASC), + FAMILY "primary" (id, city, name, address, credit_card) +); ~~~ {% include copy-clipboard.html %} ~~~ sql -> INSERT INTO t3 (name) VALUES ('a'), ('b'), ('c'); +> INSERT INTO users3 (name, city) VALUES ('Blake', 'chicago'), ('Hannah', 'seattle'), ('Bobby', 'seattle'); ~~~ {% include copy-clipboard.html %} ~~~ sql -> SELECT * FROM t3; +> SELECT * FROM users3; ~~~ ~~~ -+--------------------+------+ -| id | name | -+--------------------+------+ -| 293807573840855041 | a | -| 293807573840887809 | b | -| 293807573840920577 | c | -+--------------------+------+ + id | city | name | address | credit_card ++--------------------+---------+--------+---------+-------------+ + 469048192112197633 | chicago | Blake | NULL | NULL + 469048192112263169 | seattle | Hannah | NULL | NULL + 469048192112295937 | seattle | Bobby | NULL | NULL (3 rows) ~~~ diff --git a/_includes/v19.2/misc/force-index-selection.md b/_includes/v19.2/misc/force-index-selection.md index dd60b8217c5..cc9798bdd7d 100644 --- a/_includes/v19.2/misc/force-index-selection.md +++ b/_includes/v19.2/misc/force-index-selection.md @@ -47,14 +47,14 @@ you can check the scan direction with: {% include copy-clipboard.html %} ~~~ sql -> EXPLAIN (opt) SELECT * FROM kv@{FORCE_INDEX=primary,DESC}; +> EXPLAIN (opt) SELECT * FROM users@{FORCE_INDEX=primary,DESC}; ~~~ ~~~ - text -------------------------------------- - scan kv,rev - └── flags: force-index=primary,rev + text ++-------------------------------------+ + scan users,rev + └── flags: force-index=primary,rev (2 rows) ~~~ diff --git a/_includes/v19.2/performance/overview.md b/_includes/v19.2/performance/overview.md index 5ef839d3022..0aa12ce0075 100644 --- a/_includes/v19.2/performance/overview.md +++ b/_includes/v19.2/performance/overview.md @@ -19,7 +19,7 @@ To reproduce the performance demonstrated in this tutorial: ### Schema -Your schema and data will be based on our open-source, fictional peer-to-peer ride-sharing application,[MovR](https://github.com/cockroachdb/movr). +Your schema and data will be based on our open-source, fictional peer-to-peer vehicle-sharing application, [MovR](movr.html). Perf tuning schema diff --git a/_includes/v19.2/sql/movr-start.md b/_includes/v19.2/sql/movr-start.md new file mode 100644 index 00000000000..513e98db48a --- /dev/null +++ b/_includes/v19.2/sql/movr-start.md @@ -0,0 +1,36 @@ +- Run [`cockroach demo movr`](cockroach-demo.html) to open an interactive SQL shell to a temporary, in-memory cluster with the `movr` database preloaded and set as the [current database](sql-name-resolution.html#current-database). + + {% include copy-clipboard.html %} + ~~~ shell + $ cockroach demo movr + ~~~ + +- Use [`cockroach workload`](cockroach-workload.html): + + 1. Start an [insecure](start-a-local-cluster.html) local cluster. + + {% include copy-clipboard.html %} + ~~~ shell + $ cockroach start --insecure + ~~~ + + 2. Run `cockroach workload init movr` with the appropriate flags and [connection string](connection-parameters.html) to initialize and populate the `movr` database on your running cluster. + + {% include copy-clipboard.html %} + ~~~ shell + $ cockroach workload init movr + ~~~ + + 3. Open an interactive SQL shell to the cluster with the [`cockroach sql`](use-the-built-in-sql-client.html) command. + + {% include copy-clipboard.html %} + ~~~ shell + $ cockroach sql + ~~~ + + 4. Set `movr` as the [current database](sql-name-resolution.html#current-database) for the session. + + {% include copy-clipboard.html %} + ~~~ sql + > USE movr; + ~~~ diff --git a/_includes/v19.2/sql/movr-statements-no-data.md b/_includes/v19.2/sql/movr-statements-no-data.md new file mode 100644 index 00000000000..aaf66a35cef --- /dev/null +++ b/_includes/v19.2/sql/movr-statements-no-data.md @@ -0,0 +1,10 @@ +The following examples use MovR, a fictional vehicle-sharing application, to demonstrate CockroachDB SQL statements. For more information about the MovR example application, see [MovR: A Global Vehicle-sharing App](movr.html). + +To follow along, do the following: + +1. Start up a [secure](secure-a-cluster.html) or [insecure](start-a-local-cluster.html) local cluster. +1. Open an interactive SQL shell to the cluster with the [`cockroach sql`](use-the-built-in-sql-client.html) command. +1. Create the `movr` database with the [`CREATE DATABASE`](create-table.html) statement. +1. Set `movr` as the [current database](sql-name-resolution.html#current-database) for the session with the [`SET`](set-vars.html) statement. + +You can alternatively run `cockroach demo` to open an interactive SQL shell to a temporary, in-memory cluster, and then complete steps 3 and 4. diff --git a/_includes/v19.2/sql/movr-statements.md b/_includes/v19.2/sql/movr-statements.md new file mode 100644 index 00000000000..1ee510edd83 --- /dev/null +++ b/_includes/v19.2/sql/movr-statements.md @@ -0,0 +1,7 @@ +### 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](movr.html). + +To follow along with the example statements, do one of the following: + +{% include {{page.version.version}}/sql/movr-start.md %} diff --git a/v19.2/add-constraint.md b/v19.2/add-constraint.md index e9dca5049e3..a2c0870aa39 100644 --- a/v19.2/add-constraint.md +++ b/v19.2/add-constraint.md @@ -32,7 +32,7 @@ The user must have the `CREATE` [privilege](authorization.html#assign-privileges -----------|------------- `table_name` | The name of the table containing the column you want to constrain. `constraint_name` | The name of the constraint, which must be unique to its table and follow these [identifier rules](keywords-and-identifiers.html#identifiers). - `constraint_elem` | The [`CHECK`](check.html), [foreign key](foreign-key.html), [`UNIQUE`](unique.html) constraint you want to add.

Adding/changing a `DEFAULT` constraint is done through [`ALTER COLUMN`](alter-column.html).

Adding/changing the table's `PRIMARY KEY` is not supported through `ALTER TABLE`; it can only be specified during [table creation](create-table.html#create-a-table-primary-key-defined). + `constraint_elem` | The [`CHECK`](check.html), [foreign key](foreign-key.html), [`UNIQUE`](unique.html) constraint you want to add.

Adding/changing a `DEFAULT` constraint is done through [`ALTER COLUMN`](alter-column.html).

Adding/changing the table's `PRIMARY KEY` is not supported through `ALTER TABLE`; it can only be specified during [table creation](create-table.html). ## Viewing schema changes diff --git a/v19.2/cockroach-demo.md b/v19.2/cockroach-demo.md index b1a3df9deb8..cbfb2aa2e23 100644 --- a/v19.2/cockroach-demo.md +++ b/v19.2/cockroach-demo.md @@ -34,6 +34,7 @@ Workload | Description ---------|------------ `bank` | A `bank` database, with one `bank` table containing account details. `intro` | An `intro` database, with one table, `mytable`, with a hidden message. +`movr` | A `movr` database, with several tables of data for the [MovR example application](movr.html). `startrek` | A `startrek` database, with two tables, `episodes` and `quotes`. `tpcc` | A `tpcc` database, with a rich schema of multiple tables. diff --git a/v19.2/cockroach-workload.md b/v19.2/cockroach-workload.md index 4913b48b511..cba7132aa43 100644 --- a/v19.2/cockroach-workload.md +++ b/v19.2/cockroach-workload.md @@ -48,6 +48,7 @@ Workload | Description `bank` | Models a set of accounts with currency balances.

For this workload, you run `workload init` to load the schema and then `workload run` to generate data. `intro` | Loads an `intro` database, with one table, `mytable`, with a hidden message.

For this workload, you run only `workload init` to load the data. The `workload run` subcommand is not applicable. `kv` | Reads and writes to keys spread (by default, uniformly at random) across the cluster.

For this workload, you run `workload init` to load the schema and then `workload run` to generate data. +`movr` | Loads a `movr` database, with several tables of data for the [MovR example application](movr.html).

For this workload, you run only `workload init` to load the data. The `workload run` subcommand is not applicable. `startrek` | Loads a `startrek` database, with two tables, `episodes` and `quotes`.

For this workload, you run only `workload init` to load the data. The `workload run` subcommand is not applicable. `tpcc` | Simulates a transaction processing workload using a rich schema of multiple tables.

For this workload, you run `workload init` to load the schema and then `workload run` to generate data. `ycsb` | Simulates a high-scale key value workload, either read-heavy, write-heavy, or scan-based, with additional customizations.

For this workload, you run `workload init` to load the schema and then `workload run` to generate data. @@ -87,6 +88,7 @@ Flag | Description -----|------------ `--drop` | Drop the existing database, if it exists, before loading the dataset. + ### `kv` workload Flag | Description @@ -111,6 +113,25 @@ Flag | Description `--use-opt` | Use [cost-based optimizer](cost-based-optimizer.html).

**Applicable commands:** `init` or `run`
**Default:** `true` `--write-seq` | Initial write sequence value.

**Applicable commands:** `init` or `run` +### `movr` workload + +{{site.data.alerts.callout_info}} +This workload generates data but does not offer the ability to run continuous load. Thus, only the `init` subcommand is supported. +{{site.data.alerts.end}} + +Flag | Description +-----|------------ +`--concurrency` | The number of concurrent workers.

**Default:** `16` +`--db` | The SQL database to use.

**Default:** `movr` +`--drop` | Drop the existing database, if it exists. +`--method` | The SQL issue method (`prepare`, `noprepare`, `simple`).

**Default:** `prepare` +`--num-histories` | The initial number of ride location histories.

**Default:** `1000` +`--num-promo-codes` | The initial number of promo codes.

**Default:** `1000` +`--num-rides` | Initial number of rides.

**Default:** `500` +`--num-users` | Initial number of users.

**Default:** `50` +`--num-vehicles` | Initial number of vehicles.

**Default:** `15` +`--seed` | The random number generator seed.

**Default:** `1` + ### `tpcc` workload Flag | Description @@ -155,7 +176,6 @@ Flag | Description `--max-ops` | The maximum number of operations to run.

**Applicable command:** `run` `--max-rate` | The maximum frequency of operations (reads/writes).

**Applicable command:** `run`
**Default:** `0`, which means unlimited. `--method` | The SQL issue method (`prepare`, `noprepare`, `simple`).

**Applicable commands:** `init` or `run`
**Default:** `prepare` -`--pprofport` | The port for pprof endpoint.

**Applicable commands:** `init` or `run`. For the `run` command, this flag must be used in conjunction with `--init`.
**Default:** `33333` `--ramp` | The duration over which to ramp up load.

**Applicable command:** `run` `--request-distribution` | Distribution for the random number generator (`zipfian`, `uniform`).

**Applicable commands:** `init` or `run`.
**Default:** `zipfian` `--seed` | The random number generator seed.

**Applicable commands:** `init` or `run`
**Default:** `1` @@ -382,6 +402,56 @@ $ cockroach start \ (14 rows) ~~~ +### Load the `movr` dataset + +1. Load the dataset: + + {% include copy-clipboard.html %} + ~~~ shell + $ cockroach workload init movr \ + 'postgresql://root@localhost:26257?sslmode=disable' + ~~~ + +2. Launch the built-in SQL client to view it: + + {% include copy-clipboard.html %} + ~~~ shell + $ cockroach sql --insecure + ~~~ + + {% include copy-clipboard.html %} + ~~~ sql + > SHOW TABLES FROM movr; + ~~~ + + ~~~ + table_name ++----------------------------+ + promo_codes + rides + user_promo_codes + users + vehicle_location_histories + vehicles +(6 rows) + ~~~ + + {% include copy-clipboard.html %} + ~~~ sql + > SELECT * FROM movr.users WHERE city='new york'; + ~~~ + + ~~~ + id | city | name | address | credit_card ++--------------------------------------+----------+------------------+-----------------------------+-------------+ + 00000000-0000-4000-8000-000000000000 | new york | Robert Murphy | 99176 Anderson Mills | 8885705228 + 051eb851-eb85-4ec0-8000-000000000001 | new york | James Hamilton | 73488 Sydney Ports Suite 57 | 8340905892 + 0a3d70a3-d70a-4d80-8000-000000000002 | new york | Judy White | 18580 Rosario Ville Apt. 61 | 2597958636 + 0f5c28f5-c28f-4c00-8000-000000000003 | new york | Devin Jordan | 81127 Angela Ferry Apt. 8 | 5614075234 + 147ae147-ae14-4b00-8000-000000000004 | new york | Catherine Nelson | 1149 Lee Alley | 0792553487 +(5 rows) + ~~~ + ### Run the `tpcc` workload 1. Load the initial schema and data: diff --git a/v19.2/create-index.md b/v19.2/create-index.md index 60413194ff4..bb075cb6eb0 100644 --- a/v19.2/create-index.md +++ b/v19.2/create-index.md @@ -51,6 +51,8 @@ The user must have the `CREATE` [privilege](authorization.html#assign-privileges ## Examples +{% include {{page.version.version}}/sql/movr-statements.md %} + ### Create standard indexes To create the most efficient indexes, we recommend reviewing: @@ -64,7 +66,7 @@ Single-column indexes sort the values of a single column. {% include copy-clipboard.html %} ~~~ sql -> CREATE INDEX ON products (price); +> CREATE INDEX ON users (name); ~~~ Because each query can only use one index, single-column indexes are not typically as useful as multiple-column indexes. @@ -75,7 +77,7 @@ Multiple-column indexes sort columns in the order you list them. {% include copy-clipboard.html %} ~~~ sql -> CREATE INDEX ON products (price, stock); +> CREATE INDEX ON users (name, city); ~~~ To create the most useful multiple-column indexes, we recommend reviewing our [best practices](indexes.html#indexing-columns). @@ -86,14 +88,14 @@ Unique indexes do not allow duplicate values among their columns. {% include copy-clipboard.html %} ~~~ sql -> CREATE UNIQUE INDEX ON products (name, manufacturer_id); +> CREATE UNIQUE INDEX ON users (name, id); ~~~ This also applies the [`UNIQUE` constraint](unique.html) at the table level, similarly to [`ALTER TABLE`](alter-table.html). The above example is equivalent to: {% include copy-clipboard.html %} ~~~ sql -> ALTER TABLE products ADD CONSTRAINT products_name_manufacturer_id_key UNIQUE (name, manufacturer_id); +> ALTER TABLE users ADD CONSTRAINT users_name_id_key UNIQUE (name, id); ~~~ ### Create inverted indexes @@ -102,14 +104,14 @@ This also applies the [`UNIQUE` constraint](unique.html) at the table level, sim {% include copy-clipboard.html %} ~~~ sql -> CREATE INVERTED INDEX ON users (profile); +> CREATE INVERTED INDEX ON promo_codes (rules); ~~~ The above example is equivalent to the following PostgreSQL-compatible syntax: {% include copy-clipboard.html %} ~~~ sql -> CREATE INDEX ON users USING GIN (profile); +> CREATE INDEX ON promo_codes USING GIN (rules); ~~~ ### Store columns @@ -118,10 +120,10 @@ Storing a column improves the performance of queries that retrieve (but do not f {% include copy-clipboard.html %} ~~~ sql -> CREATE INDEX ON products (price) STORING (name); +> CREATE INDEX ON users (city) STORING (name); ~~~ -However, to use stored columns, queries must filter another column in the same index. For example, SQL can retrieve `name` values from the above index only when a query's `WHERE` clause filters `price`. +However, to use stored columns, queries must filter another column in the same index. For example, SQL can retrieve `name` values from the above index only when a query's `WHERE` clause filters `city`. ### Change column sort order @@ -129,7 +131,7 @@ To sort columns in descending order, you must explicitly set the option when cre {% include copy-clipboard.html %} ~~~ sql -> CREATE INDEX ON products (price DESC, stock); +> CREATE INDEX ON users (city DESC, name); ~~~ How columns are sorted impacts the order of rows returned by queries using the index, which particularly affects queries using `LIMIT`. @@ -140,23 +142,34 @@ Normally, CockroachDB selects the index that it calculates will scan the fewest {% include copy-clipboard.html %} ~~~ sql -> SHOW INDEX FROM products; +> SHOW INDEX FROM users; ~~~ ~~~ -+------------+--------------------+------------+--------------+-------------+-----------+---------+----------+ -| table_name | index_name | non_unique | seq_in_index | column_name | direction | storing | implicit | -+------------+--------------------+------------+--------------+-------------+-----------+---------+----------+ -| products | primary | false | 1 | id | ASC | false | false | -| products | products_price_idx | true | 1 | price | ASC | false | false | -| products | products_price_idx | true | 2 | id | ASC | false | true | -+------------+--------------------+------------+--------------+-------------+-----------+---------+----------+ -(3 rows) + table_name | index_name | non_unique | seq_in_index | column_name | direction | storing | implicit ++------------+----------------+------------+--------------+-------------+-----------+---------+----------+ + users | primary | false | 1 | city | ASC | false | false + users | primary | false | 2 | id | ASC | false | false + users | users_name_idx | true | 1 | name | ASC | false | false + users | users_name_idx | true | 2 | city | ASC | false | true + users | users_name_idx | true | 3 | id | ASC | false | true +(5 rows) ~~~ {% include copy-clipboard.html %} ~~~ sql -> SELECT name FROM products@products_price_idx WHERE price > 10; +> SELECT name FROM users@users_name_idx WHERE city='new york'; +~~~ + +~~~ + name ++------------------+ + Catherine Nelson + Devin Jordan + James Hamilton + Judy White + Robert Murphy +(5 rows) ~~~ ## See also diff --git a/v19.2/create-table.md b/v19.2/create-table.md index a2ac2d2bad8..7d2dc8553ba 100644 --- a/v19.2/create-table.md +++ b/v19.2/create-table.md @@ -95,148 +95,92 @@ CockroachDB allows [enterprise users](enterprise-licensing.html) to [define tabl ## Examples -### Create a table (no primary key defined) +### Create a table -In CockroachDB, every table requires a [primary key](primary-key.html). If one is not explicitly defined, a column called `rowid` of the type `INT` is added automatically as the primary key, with the `unique_rowid()` function used to ensure that new rows always default to unique `rowid` values. The primary key is automatically indexed. +In this example, we create the `users` table with a single [primary key](primary-key.html) column defined. In CockroachDB, every table requires a [primary key](primary-key.html). If one is not explicitly defined, a column called `rowid` of the type `INT` is added automatically as the primary key, with the `unique_rowid()` function used to ensure that new rows always default to unique `rowid` values. The primary key is automatically indexed. {{site.data.alerts.callout_info}}Strictly speaking, a primary key's unique index is not created; it is derived from the key(s) under which the data is stored, so it takes no additional space. However, it appears as a normal unique index when using commands like SHOW INDEX.{{site.data.alerts.end}} {% include copy-clipboard.html %} ~~~ sql -> CREATE TABLE logon ( - user_id INT, - logon_date DATE +> CREATE TABLE users ( + id UUID PRIMARY KEY, + city STRING, + name STRING, + address STRING, + credit_card STRING, + dl STRING ); ~~~ {% include copy-clipboard.html %} ~~~ sql -> SHOW COLUMNS FROM logon; +> SHOW COLUMNS FROM users; ~~~ ~~~ -+-------------+-----------+-------------+----------------+-----------------------+---------+ -| column_name | data_type | is_nullable | column_default | generation_expression | indices | -+-------------+-----------+-------------+----------------+-----------------------+---------+ -| user_id | INT | true | NULL | | {} | -| logon_date | DATE | true | NULL | | {} | -+-------------+-----------+-------------+----------------+-----------------------+---------+ -(2 rows) + column_name | data_type | is_nullable | column_default | generation_expression | indices | is_hidden ++-------------+-----------+-------------+----------------+-----------------------+-----------+-----------+ + id | UUID | false | NULL | | {primary} | false + city | STRING | true | NULL | | {} | false + name | STRING | true | NULL | | {} | false + address | STRING | true | NULL | | {} | false + credit_card | STRING | true | NULL | | {} | false + dl | STRING | true | NULL | | {} | false +(6 rows) ~~~ {% include copy-clipboard.html %} ~~~ sql -> SHOW INDEX FROM logon; +> SHOW INDEX FROM users; ~~~ ~~~ + table_name | index_name | non_unique | seq_in_index | column_name | direction | storing | implicit +------------+------------+------------+--------------+-------------+-----------+---------+----------+ -| table_name | index_name | non_unique | seq_in_index | column_name | direction | storing | implicit | -+------------+------------+------------+--------------+-------------+-----------+---------+----------+ -| logon | primary | false | 1 | rowid | ASC | false | false | -+------------+------------+------------+--------------+-------------+-----------+---------+----------+ + users | primary | false | 1 | id | ASC | false | false (1 row) ~~~ -### Create a table (primary key defined) - -In this example, we create a table with three columns. One column is the [`PRIMARY KEY`](primary-key.html), another is given the [`UNIQUE` constraint](unique.html), and the third has no constraints. The `PRIMARY KEY` and column with the `UNIQUE` constraint are automatically indexed. - -{% include copy-clipboard.html %} -~~~ sql -> CREATE TABLE logoff ( - user_id INT PRIMARY KEY, - user_email STRING UNIQUE, - logoff_date DATE -); -~~~ - -{% include copy-clipboard.html %} -~~~ sql -> SHOW COLUMNS FROM logoff; -~~~ - -~~~ -+-------------+-----------+-------------+----------------+-----------------------+-------------------------------------+ -| column_name | data_type | is_nullable | column_default | generation_expression | indices | -+-------------+-----------+-------------+----------------+-----------------------+-------------------------------------+ -| user_id | INT | false | NULL | | {"primary","logoff_user_email_key"} | -| user_email | STRING | true | NULL | | {"logoff_user_email_key"} | -| logoff_date | DATE | true | NULL | | {} | -+-------------+-----------+-------------+----------------+-----------------------+-------------------------------------+ -(3 rows) -~~~ - -{% include copy-clipboard.html %} -~~~ sql -> SHOW INDEX FROM logoff; -~~~ - -~~~ -+------------+-----------------------+------------+--------------+-------------+-----------+---------+----------+ -| table_name | index_name | non_unique | seq_in_index | column_name | direction | storing | implicit | -+------------+-----------------------+------------+--------------+-------------+-----------+---------+----------+ -| logoff | primary | false | 1 | user_id | ASC | false | false | -| logoff | logoff_user_email_key | false | 1 | user_email | ASC | false | false | -| logoff | logoff_user_email_key | false | 2 | user_id | ASC | false | true | -+------------+-----------------------+------------+--------------+-------------+-----------+---------+----------+ -(3 rows) -~~~ - ### Create a table with secondary and inverted indexes -In this example, we create two secondary indexes during table creation. Secondary indexes allow efficient access to data with keys other than the primary key. This example also demonstrates a number of column-level and table-level [constraints](constraints.html). - -[Inverted indexes](inverted-indexes.html) allow efficient access to the schemaless data in a [`JSONB`](jsonb.html) column. - -This example also demonstrates a number of column-level and table-level [constraints](constraints.html). +In this example, we create secondary and inverted indexes during table creation. Secondary indexes allow efficient access to data with keys other than the primary key. [Inverted indexes](inverted-indexes.html) allow efficient access to the schemaless data in a [`JSONB`](jsonb.html) column. {% include copy-clipboard.html %} ~~~ sql -> CREATE TABLE product_information ( - product_id INT PRIMARY KEY NOT NULL, - product_name STRING(50) UNIQUE NOT NULL, - product_description STRING(2000), - category_id STRING(1) NOT NULL CHECK (category_id IN ('A','B','C')), - weight_class INT, - warranty_period INT CONSTRAINT valid_warranty CHECK (warranty_period BETWEEN 0 AND 24), - supplier_id INT, - product_status STRING(20), - list_price DECIMAL(8,2), - min_price DECIMAL(8,2), - catalog_url STRING(50) UNIQUE, - date_added DATE DEFAULT CURRENT_DATE(), - misc JSONB, - CONSTRAINT price_check CHECK (list_price >= min_price), - INDEX date_added_idx (date_added), - INDEX supp_id_prod_status_idx (supplier_id, product_status), - INVERTED INDEX details (misc) +> CREATE TABLE vehicles ( + id UUID NOT NULL, + city STRING NOT NULL, + type STRING, + owner_id UUID, + creation_time TIMESTAMP, + status STRING, + current_location STRING, + ext JSONB, + CONSTRAINT "primary" PRIMARY KEY (city ASC, id ASC), + INDEX vehicles_auto_index_fk_city_ref_users (city ASC, owner_id ASC), + INVERTED INDEX ix_vehicle_ext (ext), + FAMILY "primary" (id, city, type, owner_id, creation_time, status, current_location, ext) ); ~~~ {% include copy-clipboard.html %} ~~~ sql -> SHOW INDEX FROM product_information; +> SHOW INDEX FROM vehicles; ~~~ ~~~ -+---------------------+--------------------------------------+------------+--------------+----------------+-----------+---------+----------+ -| table_name | index_name | non_unique | seq_in_index | column_name | direction | storing | implicit | -+---------------------+--------------------------------------+------------+--------------+----------------+-----------+---------+----------+ -| product_information | primary | false | 1 | product_id | ASC | false | false | -| product_information | product_information_product_name_key | false | 1 | product_name | ASC | false | false | -| product_information | product_information_product_name_key | false | 2 | product_id | ASC | false | true | -| product_information | product_information_catalog_url_key | false | 1 | catalog_url | ASC | false | false | -| product_information | product_information_catalog_url_key | false | 2 | product_id | ASC | false | true | -| product_information | date_added_idx | true | 1 | date_added | ASC | false | false | -| product_information | date_added_idx | true | 2 | product_id | ASC | false | true | -| product_information | supp_id_prod_status_idx | true | 1 | supplier_id | ASC | false | false | -| product_information | supp_id_prod_status_idx | true | 2 | product_status | ASC | false | false | -| product_information | supp_id_prod_status_idx | true | 3 | product_id | ASC | false | true | -| product_information | details | true | 1 | misc | ASC | false | false | -| product_information | details | true | 2 | product_id | ASC | false | true | -+---------------------+--------------------------------------+------------+--------------+----------------+-----------+---------+----------+ -(12 rows) + table_name | index_name | non_unique | seq_in_index | column_name | direction | storing | implicit ++------------+---------------------------------------+------------+--------------+-------------+-----------+---------+----------+ + vehicles | primary | false | 1 | city | ASC | false | false + vehicles | primary | false | 2 | id | ASC | false | false + vehicles | vehicles_auto_index_fk_city_ref_users | true | 1 | city | ASC | false | false + vehicles | vehicles_auto_index_fk_city_ref_users | true | 2 | owner_id | ASC | false | false + vehicles | vehicles_auto_index_fk_city_ref_users | true | 3 | id | ASC | false | true + vehicles | ix_vehicle_ext | true | 1 | ext | ASC | false | false + vehicles | ix_vehicle_ext | true | 2 | city | ASC | false | true + vehicles | ix_vehicle_ext | true | 3 | id | ASC | false | true +(8 rows) ~~~ We also have other resources on indexes: @@ -250,13 +194,13 @@ We also have other resources on indexes: ### Create a table with a foreign key constraint -[`FOREIGN KEY` constraints](foreign-key.html) guarantee a column uses only values that already exist in the column it references, which must be from another table. This constraint enforces referential integrity between the two tables. +[Foreign key constraints](foreign-key.html) guarantee a column uses only values that already exist in the column it references, which must be from another table. This constraint enforces referential integrity between the two tables. There are a [number of rules](foreign-key.html#rules-for-creating-foreign-keys) that govern foreign keys, but the two most important are: - Foreign key columns must be [indexed](indexes.html) when creating the table using `INDEX`, `PRIMARY KEY`, or `UNIQUE`. -- Referenced columns must contain only unique values. This means the `REFERENCES` clause must use exactly the same columns as a [`PRIMARY KEY`](primary-key.html) or [`UNIQUE`](unique.html) constraint. +- Referenced columns must contain only unique values. This means the `REFERENCES` clause must use exactly the same columns as a [primary key](primary-key.html) or [unique](unique.html) constraint. You can include a [foreign key action](foreign-key.html#foreign-key-actions) to specify what happens when a column referenced by a foreign key constraint is updated or deleted. The default actions are `ON UPDATE NO ACTION` and `ON DELETE NO ACTION`. @@ -264,74 +208,156 @@ In this example, we use `ON DELETE CASCADE` (i.e., when row referenced by a fore {% include copy-clipboard.html %} ~~~ sql -> CREATE TABLE customers ( - id INT PRIMARY KEY, - name STRING - ); +> CREATE TABLE users ( + id UUID PRIMARY KEY DEFAULT gen_random_uuid(), + city STRING, + name STRING, + address STRING, + credit_card STRING, + dl STRING UNIQUE CHECK (LENGTH(dl) < 8) +); +~~~ + +{% include copy-clipboard.html %} +~~~ sql +> CREATE TABLE vehicles ( + id UUID NOT NULL DEFAULT gen_random_uuid(), + city STRING NOT NULL, + type STRING, + owner_id UUID REFERENCES users(id) ON DELETE CASCADE, + creation_time TIMESTAMP, + status STRING, + current_location STRING, + ext JSONB, + CONSTRAINT "primary" PRIMARY KEY (city ASC, id ASC), + INDEX vehicles_auto_index_fk_city_ref_users (city ASC, owner_id ASC), + INVERTED INDEX ix_vehicle_ext (ext), + FAMILY "primary" (id, city, type, owner_id, creation_time, status, current_location, ext) +); +~~~ + +{% include copy-clipboard.html %} +~~~ sql +> SHOW CREATE TABLE vehicles; +~~~ + +~~~ + table_name | create_statement ++------------+-----------------------------------------------------------------------------------------------------+ + vehicles | CREATE TABLE vehicles ( + | id UUID NOT NULL DEFAULT gen_random_uuid(), + | city STRING NOT NULL, + | type STRING NULL, + | owner_id UUID NULL, + | creation_time TIMESTAMP NULL, + | status STRING NULL, + | current_location STRING NULL, + | ext JSONB NULL, + | CONSTRAINT "primary" PRIMARY KEY (city ASC, id ASC), + | INDEX vehicles_auto_index_fk_city_ref_users (city ASC, owner_id ASC), + | INVERTED INDEX ix_vehicle_ext (ext), + | CONSTRAINT fk_owner_id_ref_users FOREIGN KEY (owner_id) REFERENCES users(id) ON DELETE CASCADE, + | INDEX vehicles_auto_index_fk_owner_id_ref_users (owner_id ASC), + | FAMILY "primary" (id, city, type, owner_id, creation_time, status, current_location, ext) + | ) +(1 row) ~~~ {% include copy-clipboard.html %} ~~~ sql -> CREATE TABLE orders ( - id INT PRIMARY KEY, - customer_id INT REFERENCES customers(id) ON DELETE CASCADE - ); +> INSERT INTO users (name, dl) VALUES ('Annika', 'ABC-123'); ~~~ {% include copy-clipboard.html %} ~~~ sql -> SHOW CREATE orders; -~~~ - -~~~ -+------------+--------------------------------------------------------------------------+ -| table_name | create_statement | -+------------+--------------------------------------------------------------------------+ -| orders | CREATE TABLE orders ( | -| | | -| | id INT NOT NULL, | -| | | -| | customer_id INT NULL, | -| | | -| | CONSTRAINT "primary" PRIMARY KEY (id ASC), | -| | | -| | CONSTRAINT fk_customer_id_ref_customers FOREIGN KEY (customer_id) | -| | REFERENCES customers (id) ON DELETE CASCADE, | -| | | -| | INDEX orders_auto_index_fk_customer_id_ref_customers (customer_id | -| | ASC), | -| | | -| | FAMILY "primary" (id, customer_id) | -| | | -| | ) | -+------------+--------------------------------------------------------------------------+ +> SELECT * FROM users; +~~~ + +~~~ + id | city | name | address | credit_card | dl ++--------------------------------------+------+--------+---------+-------------+---------+ + 26da1fce-59e1-4290-a786-9068242dd195 | NULL | Annika | NULL | NULL | ABC-123 +(1 row) +~~~ + +{% include copy-clipboard.html %} +~~~ sql +> INSERT INTO vehicles (city, owner_id) VALUES ('seattle', '26da1fce-59e1-4290-a786-9068242dd195'); +~~~ + +{% include copy-clipboard.html %} +~~~ sql +> SELECT * FROM vehicles; +~~~ + +~~~ + id | city | type | owner_id | creation_time | status | current_location | ext ++--------------------------------------+---------+------+--------------------------------------+---------------+--------+------------------+------+ + fc6f7a8c-4ba9-42e1-9c37-7be3c906050c | seattle | NULL | 26da1fce-59e1-4290-a786-9068242dd195 | NULL | NULL | NULL | NULL (1 row) ~~~ {% include copy-clipboard.html %} ~~~ sql -> INSERT INTO customers VALUES (1, 'Lauren'); +> DELETE FROM users WHERE id = '26da1fce-59e1-4290-a786-9068242dd195'; ~~~ {% include copy-clipboard.html %} ~~~ sql -> INSERT INTO orders VALUES (1,1); +> SELECT * FROM vehicles; +~~~ ~~~ + id | city | type | owner_id | creation_time | status | current_location | ext ++----+------+------+----------+---------------+--------+------------------+-----+ +(0 rows) +~~~ + + +### Create a table with a check constraint + +In this example, we create the `users` table, but with some column [constraints](constraints.html). One column is the [primary key](primary-key.html), and another column is given a [unique constraint](unique.html) and a [check constraint](check.html) that limits the length of the string. Primary key columns and columns with unique constraints are automatically indexed. {% include copy-clipboard.html %} ~~~ sql -> DELETE FROM customers WHERE id = 1; +> CREATE TABLE users ( + id UUID PRIMARY KEY, + city STRING, + name STRING, + address STRING, + credit_card STRING, + dl STRING UNIQUE CHECK (LENGTH(dl) < 8) +); ~~~ {% include copy-clipboard.html %} ~~~ sql -> SELECT * FROM orders; +> SHOW COLUMNS FROM users; ~~~ + ~~~ -+----+-------------+ -| id | customer_id | -+----+-------------+ -+----+-------------+ + column_name | data_type | is_nullable | column_default | generation_expression | indices | is_hidden ++-------------+-----------+-------------+----------------+-----------------------+------------------------+-----------+ + id | UUID | false | NULL | | {primary,users_dl_key} | false + city | STRING | true | NULL | | {} | false + name | STRING | true | NULL | | {} | false + address | STRING | true | NULL | | {} | false + credit_card | STRING | true | NULL | | {} | false + dl | STRING | true | NULL | | {users_dl_key} | false +(6 rows) +~~~ + +{% include copy-clipboard.html %} +~~~ sql +> SHOW INDEX FROM users; +~~~ + +~~~ + table_name | index_name | non_unique | seq_in_index | column_name | direction | storing | implicit ++------------+--------------+------------+--------------+-------------+-----------+---------+----------+ + users | primary | false | 1 | id | ASC | false | false + users | users_dl_key | false | 1 | dl | ASC | false | false + users | users_dl_key | false | 2 | id | ASC | false | true +(3 rows) ~~~ ### Create a table that mirrors key-value storage @@ -340,39 +366,43 @@ In this example, we use `ON DELETE CASCADE` (i.e., when row referenced by a fore ### Create a table from a `SELECT` statement -You can use the [`CREATE TABLE AS`](create-table-as.html) statement to create a new table from the results of a `SELECT` statement, for example: +You can use the [`CREATE TABLE AS`](create-table-as.html) statement to create a new table from the results of a `SELECT` statement. For example, suppose you have a number of rows of user data in the `users` table, and you want to create a new table from the subset of users that are located in New York. {% include copy-clipboard.html %} ~~~ sql -> SELECT * FROM customers WHERE state = 'NY'; +> SELECT * FROM users WHERE city = 'new york'; ~~~ ~~~ -+----+---------+-------+ -| id | name | state | -+----+---------+-------+ -| 6 | Dorotea | NY | -| 15 | Thales | NY | -+----+---------+-------+ + id | city | name | address | credit_card ++--------------------------------------+----------+------------------+-----------------------------+-------------+ + 00000000-0000-4000-8000-000000000000 | new york | Robert Murphy | 99176 Anderson Mills | 8885705228 + 051eb851-eb85-4ec0-8000-000000000001 | new york | James Hamilton | 73488 Sydney Ports Suite 57 | 8340905892 + 0a3d70a3-d70a-4d80-8000-000000000002 | new york | Judy White | 18580 Rosario Ville Apt. 61 | 2597958636 + 0f5c28f5-c28f-4c00-8000-000000000003 | new york | Devin Jordan | 81127 Angela Ferry Apt. 8 | 5614075234 + 147ae147-ae14-4b00-8000-000000000004 | new york | Catherine Nelson | 1149 Lee Alley | 0792553487 +(5 rows) ~~~ {% include copy-clipboard.html %} ~~~ sql -> CREATE TABLE customers_ny AS SELECT * FROM customers WHERE state = 'NY'; +> CREATE TABLE users_ny AS SELECT * FROM users WHERE city = 'new york'; ~~~ {% include copy-clipboard.html %} ~~~ sql -> SELECT * FROM customers_ny; +> SELECT * FROM users_ny; ~~~ ~~~ -+----+---------+-------+ -| id | name | state | -+----+---------+-------+ -| 6 | Dorotea | NY | -| 15 | Thales | NY | -+----+---------+-------+ + id | city | name | address | credit_card ++--------------------------------------+----------+------------------+-----------------------------+-------------+ + 00000000-0000-4000-8000-000000000000 | new york | Robert Murphy | 99176 Anderson Mills | 8885705228 + 051eb851-eb85-4ec0-8000-000000000001 | new york | James Hamilton | 73488 Sydney Ports Suite 57 | 8340905892 + 0a3d70a3-d70a-4d80-8000-000000000002 | new york | Judy White | 18580 Rosario Ville Apt. 61 | 2597958636 + 0f5c28f5-c28f-4c00-8000-000000000003 | new york | Devin Jordan | 81127 Angela Ferry Apt. 8 | 5614075234 + 147ae147-ae14-4b00-8000-000000000004 | new york | Catherine Nelson | 1149 Lee Alley | 0792553487 +(5 rows) ~~~ ### Create a table with a computed column @@ -391,17 +421,26 @@ In this example, we create a table and [define partitions by list](partitioning. {% include copy-clipboard.html %} ~~~ sql -> CREATE TABLE students_by_list ( - id INT DEFAULT unique_rowid(), - name STRING, - email STRING, - country STRING, - expected_graduation_date DATE, - PRIMARY KEY (country, id)) - PARTITION BY LIST (country) - (PARTITION north_america VALUES IN ('CA','US'), - PARTITION australia VALUES IN ('AU','NZ'), - PARTITION DEFAULT VALUES IN (default)); +> CREATE TABLE TABLE rides ( + id UUID NOT NULL, + city STRING NOT NULL, + vehicle_city STRING, + rider_id UUID, + vehicle_id UUID, + start_address STRING, + end_address STRING, + start_time TIMESTAMP, + end_time TIMESTAMP, + revenue DECIMAL(10,2), + CONSTRAINT "primary" PRIMARY KEY (city ASC, id ASC), + INDEX rides_auto_index_fk_city_ref_users (city ASC, rider_id ASC), + INDEX rides_auto_index_fk_vehicle_city_ref_vehicles (vehicle_city ASC, vehicle_id ASC), + FAMILY "primary" (id, city, vehicle_city, rider_id, vehicle_id, start_address, end_address, start_time, end_time, revenue), + CONSTRAINT check_vehicle_city_city CHECK (vehicle_city = city)) + PARTITION BY LIST (city) + (PARTITION new_york VALUES IN ('new york'), + PARTITION chicago VALUES IN ('chicago'), + PARTITION seattle VALUES IN ('seattle')); ~~~ #### Create a table with partitions by range @@ -410,16 +449,26 @@ In this example, we create a table and [define partitions by range](partitioning {% include copy-clipboard.html %} ~~~ sql -> CREATE TABLE students_by_range ( - id INT DEFAULT unique_rowid(), - name STRING, - email STRING, - country STRING, - expected_graduation_date DATE, - PRIMARY KEY (expected_graduation_date, id)) - PARTITION BY RANGE (expected_graduation_date) - (PARTITION graduated VALUES FROM (MINVALUE) TO ('2017-08-15'), - PARTITION current VALUES FROM ('2017-08-15') TO (MAXVALUE)); +> CREATE TABLE rides ( + id UUID NOT NULL, + city STRING NOT NULL, + vehicle_city STRING, + rider_id UUID, + vehicle_id UUID, + start_address STRING, + end_address STRING, + start_time TIMESTAMP, + end_time TIMESTAMP, + ride_length INTERVAL as (start_time - end_time) STORED, + revenue DECIMAL(10,2), + CONSTRAINT "primary" PRIMARY KEY (ride_length ASC, city ASC, id ASC), + INDEX rides_auto_index_fk_city_ref_users (city ASC, rider_id ASC), + INDEX rides_auto_index_fk_vehicle_city_ref_vehicles (vehicle_city ASC, vehicle_id ASC), + FAMILY "primary" (id, city, vehicle_city, rider_id, vehicle_id, start_address, end_address, start_time, end_time, revenue), + CONSTRAINT check_vehicle_city_city CHECK (vehicle_city = city)) + PARTITION BY RANGE (ride_length) + (PARTITION short_rides VALUES FROM ('0 seconds') TO ('30 minutes'), + PARTITION long_rides VALUES FROM ('30 minutes') TO (MAXVALUE)); ~~~ ### Show the definition of a table @@ -428,29 +477,33 @@ To show the definition of a table, use the [`SHOW CREATE`](show-create.html) sta {% include copy-clipboard.html %} ~~~ sql -> SHOW CREATE logoff; -~~~ - -~~~ -+------------+----------------------------------------------------------+ -| table_name | create_statement | -+------------+----------------------------------------------------------+ -| logoff | CREATE TABLE logoff ( | -| | | -| | user_id INT NOT NULL, | -| | | -| | user_email STRING NULL, | -| | | -| | logoff_date DATE NULL, | -| | | -| | CONSTRAINT "primary" PRIMARY KEY (user_id ASC), | -| | | -| | UNIQUE INDEX logoff_user_email_key (user_email ASC), | -| | | -| | FAMILY "primary" (user_id, user_email, logoff_date) | -| | | -| | ) | -+------------+----------------------------------------------------------+ +> SHOW CREATE rides; +~~~ + +~~~ + table_name | create_statement ++------------+----------------------------------------------------------------------------------------------------------------------------------------------+ + rides | CREATE TABLE rides ( + | id UUID NOT NULL, + | city STRING NOT NULL, + | vehicle_city STRING NULL, + | rider_id UUID NULL, + | vehicle_id UUID NULL, + | start_address STRING NULL, + | end_address STRING NULL, + | start_time TIMESTAMP NULL, + | end_time TIMESTAMP NULL, + | ride_length INTERVAL NOT NULL AS (start_time - end_time) STORED, + | revenue DECIMAL(10,2) NULL, + | CONSTRAINT "primary" PRIMARY KEY (ride_length ASC, city ASC, id ASC), + | INDEX rides_auto_index_fk_city_ref_users (city ASC, rider_id ASC), + | INDEX rides_auto_index_fk_vehicle_city_ref_vehicles (vehicle_city ASC, vehicle_id ASC), + | FAMILY "primary" (id, city, vehicle_city, rider_id, vehicle_id, start_address, end_address, start_time, end_time, revenue, ride_length), + | CONSTRAINT check_vehicle_city_city CHECK (vehicle_city = city) + | ) PARTITION BY RANGE (ride_length) ( + | PARTITION short_rides VALUES FROM ('00:00:00') TO ('00:30:00'), + | PARTITION long_rides VALUES FROM ('00:30:00') TO (MAXVALUE) + | ) (1 row) ~~~ diff --git a/v19.2/delete.md b/v19.2/delete.md index 32d9d016f59..137f9763a89 100644 --- a/v19.2/delete.md +++ b/v19.2/delete.md @@ -83,16 +83,39 @@ For an explanation of why this happens, and for instructions showing how to iter ## Examples +{% include {{page.version.version}}/sql/movr-statements.md %} + ### Delete all rows You can delete all rows from a table by not including a `WHERE` clause in your `DELETE` statement. +{{site.data.alerts.callout_info}} +If the [`sql_safe_updates`](use-the-built-in-sql-client.html#allow-potentially-unsafe-sql-statements) session variable is set to `true`, the client will prevent the update. `sql_safe_updates` is set to `true` by default. +{{site.data.alerts.end}} + +{% include copy-clipboard.html %} +~~~ sql +> DELETE FROM vehicle_location_histories; +~~~ + +~~~ +pq: rejected: DELETE without WHERE clause (sql_safe_updates = true) +~~~ + +You can use a [`SET`](set-vars.html) statement to set session variables. + +{% include copy-clipboard.html %} +~~~ sql +> SET sql_safe_updates = false; +~~~ + {% include copy-clipboard.html %} ~~~ sql -> DELETE FROM account_details; +> DELETE FROM vehicle_location_histories; ~~~ + ~~~ -DELETE 7 +DELETE 1000 ~~~ {{site.data.alerts.callout_success}} @@ -107,18 +130,13 @@ When deleting specific rows from a table, the most important decision you make i Using columns with the [Primary Key](primary-key.html) or [Unique](unique.html) constraints to delete rows ensures your statement is unambiguous—no two rows contain the same column value, so it's less likely to delete data unintentionally. -In this example, `account_id` is our primary key and we want to delete the row where it equals 1. Because we're positive no other rows have that value in the `account_id` column, there's no risk of accidentally removing another row. +In this example, `code` is our primary key and we want to delete the row where the code equals "about_stuff_city". Because we're positive no other rows have that value in the `code` column, there's no risk of accidentally removing another row. {% include copy-clipboard.html %} ~~~ sql -> DELETE FROM account_details WHERE account_id = 1 RETURNING *; +> DELETE FROM promo_codes WHERE code = 'about_stuff_city'; ~~~ ~~~ - account_id | balance | account_type -------------+---------+-------------- - 1 | 32000 | Savings -(1 row) - DELETE 1 ~~~ @@ -128,19 +146,13 @@ Deleting rows using non-unique columns removes _every_ row that returns `TRUE` f {% include copy-clipboard.html %} ~~~ sql -> DELETE FROM account_details WHERE balance = 30000 RETURNING *; +> DELETE FROM promo_codes WHERE creation_time > '2019-01-30 00:00:00+00:00'; ~~~ ~~~ - account_id | balance | account_type -------------+---------+-------------- - 2 | 30000 | Checking - 3 | 30000 | Savings -(2 rows) - -DELETE 2 +DELETE 4 ~~~ -The example statement deleted two rows, which might be unexpected. +The example statement deleted four rows, which might be unexpected. ### Return deleted rows @@ -150,34 +162,24 @@ To see which rows your statement deleted, include the `RETURNING` clause to retr By specifying `*`, you retrieve all columns of the delete rows. -{% include copy-clipboard.html %} -~~~ sql -> DELETE FROM account_details WHERE balance < 23000 RETURNING *; -~~~ -~~~ - account_id | balance | account_type -------------+---------+-------------- - 4 | 22000 | Savings -(1 row) - -DELETE 1 -~~~ - #### Use specific columns To retrieve specific columns, name them in the `RETURNING` clause. {% include copy-clipboard.html %} ~~~ sql -> DELETE FROM account_details WHERE account_id = 5 RETURNING account_id, account_type; +> DELETE FROM promo_codes WHERE creation_time > '2019-01-29 00:00:00+00:00' RETURNING code, rules; ~~~ ~~~ - account_id | account_type -------------+-------------- - 5 | Checking -(1 row) + code | rules ++------------------------+----------------------------------------------+ + box_investment_stuff | {"type": "percent_discount", "value": "10%"} + energy_newspaper_field | {"type": "percent_discount", "value": "10%"} + simple_guy_theory | {"type": "percent_discount", "value": "10%"} + study_piece_war | {"type": "percent_discount", "value": "10%"} + tv_this_list | {"type": "percent_discount", "value": "10%"} +(5 rows) -DELETE 1 ~~~ #### Change column labels @@ -186,15 +188,14 @@ When `RETURNING` specific columns, you can change their labels using `AS`. {% include copy-clipboard.html %} ~~~ sql -> DELETE FROM account_details WHERE balance < 24500 RETURNING account_id, balance AS final_balance; +> DELETE FROM promo_codes WHERE creation_time > '2019-01-28 00:00:00+00:00' RETURNING code, rules AS discount; ~~~ ~~~ - account_id | final_balance -------------+--------------- - 6 | 23500 -(1 row) - -DELETE 1 + code | discount ++---------------------+----------------------------------------------+ + chair_company_state | {"type": "percent_discount", "value": "10%"} + view_reveal_radio | {"type": "percent_discount", "value": "10%"} +(2 rows) ~~~ #### Sort and return deleted rows @@ -203,17 +204,18 @@ To sort and return deleted rows, use a statement like the following: {% include copy-clipboard.html %} ~~~ sql -> SELECT * FROM [DELETE FROM account_details RETURNING *] ORDER BY account_id; +> SELECT * FROM [DELETE FROM promo_codes WHERE creation_time > '2019-01-27 00:00:00+00:00' RETURNING *] ORDER BY expiration_time; ~~~ ~~~ - account_id | balance | account_type -------------+----------+-------------- - 7 | 79493.51 | Checking - 8 | 40761.66 | Savings - 9 | 2111.67 | Checking - 10 | 59173.15 | Savings -(4 rows) + code | description | creation_time | expiration_time | rules ++----------------------------+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+---------------------------+---------------------------+----------------------------------------------+ + often_thing_hair | Society right wish face see if pull. Great generation social bar read budget wonder natural. Somebody dark field economic material. Nature nature paper law worry common. Serious activity hospital wide none. | 2019-01-27 03:04:05+00:00 | 2019-01-29 03:04:05+00:00 | {"type": "percent_discount", "value": "10%"} + step_though_military | Director middle summer most create any. | 2019-01-27 03:04:05+00:00 | 2019-01-29 03:04:05+00:00 | {"type": "percent_discount", "value": "10%"} + own_whose_economy | Social participant order this. Guy toward nor indeed police player inside nor. Model education voice several college art on. Start listen their maybe. | 2019-01-27 03:04:05+00:00 | 2019-01-30 03:04:05+00:00 | {"type": "percent_discount", "value": "10%"} + crime_experience_certainly | Prepare right teacher mouth student. Trouble condition weight during scene something stand. | 2019-01-27 03:04:05+00:00 | 2019-01-31 03:04:05+00:00 | {"type": "percent_discount", "value": "10%"} + policy_its_wife | Player either she something good minute or. Nearly policy player receive. Somebody mean book store fire realize. | 2019-01-27 03:04:05+00:00 | 2019-01-31 03:04:05+00:00 | {"type": "percent_discount", "value": "10%"} +(5 rows) ~~~ ## See also diff --git a/v19.2/demo-geo-partitioning.md b/v19.2/demo-geo-partitioning.md index f4b1535bced..438333260d9 100644 --- a/v19.2/demo-geo-partitioning.md +++ b/v19.2/demo-geo-partitioning.md @@ -31,7 +31,7 @@ A few notes: ### Review the application -For your application, you'll use our open-source, fictional, peer-to-peer ride-sharing app, [MovR](https://github.com/cockroachdb/movr). You'll run 3 instances of MovR, one in each US region, with each instance representing users in a specific city: New York, Chicago, or Seattle. +For your application, you'll use our open-source, fictional, peer-to-peer vehicle-sharing app, [MovR](movr.html). You'll run 3 instances of MovR, one in each US region, with each instance representing users in a specific city: New York, Chicago, or Seattle. #### The schema diff --git a/v19.2/drop-table.md b/v19.2/drop-table.md index 1414c155989..f1b0ea1fb2b 100644 --- a/v19.2/drop-table.md +++ b/v19.2/drop-table.md @@ -31,29 +31,32 @@ Parameter | Description ## Examples +{% include {{page.version.version}}/sql/movr-statements.md %} + ### Remove a table (no dependencies) In this example, other objects do not depend on the table being dropped. {% include copy-clipboard.html %} ~~~ sql -> SHOW TABLES FROM bank; +> SHOW TABLES FROM movr; ~~~ ~~~ -+--------------------+ -| table_name | -+--------------------+ -| accounts | -| branches | -| user_accounts_view | -+--------------------+ -(3 rows) + table_name ++----------------------------+ + promo_codes + rides + user_promo_codes + users + vehicle_location_histories + vehicles +(6 rows) ~~~ {% include copy-clipboard.html %} ~~~ sql -> DROP TABLE bank.branches; +> DROP TABLE promo_codes; ~~~ ~~~ @@ -62,52 +65,82 @@ DROP TABLE {% include copy-clipboard.html %} ~~~ sql -> SHOW TABLES FROM bank; +> SHOW TABLES FROM movr; ~~~ ~~~ -+--------------------+ -| table_name | -+--------------------+ -| accounts | -| user_accounts_view | -+--------------------+ -(2 rows) + table_name ++----------------------------+ + rides + user_promo_codes + users + vehicle_location_histories + vehicles +(5 rows) ~~~ ### Remove a table and dependent objects with `CASCADE` -In this example, a view depends on the table being dropped. Therefore, it's only possible to drop the table while simultaneously dropping the dependent view using `CASCADE`. +In this example, a [foreign key](foreign-key.html) from a different table references the table being dropped. Therefore, it's only possible to drop the table while simultaneously dropping the dependent foreign key constraint using `CASCADE`. {{site.data.alerts.callout_danger}}CASCADE drops all dependent objects without listing them, which can lead to inadvertent and difficult-to-recover losses. To avoid potential harm, we recommend dropping objects individually in most cases.{{site.data.alerts.end}} {% include copy-clipboard.html %} ~~~ sql -> SHOW TABLES FROM bank; +> SHOW TABLES FROM movr; ~~~ ~~~ -+--------------------+ -| table_name | -+--------------------+ -| accounts | -| user_accounts_view | -+--------------------+ -(2 rows) + table_name ++----------------------------+ + rides + user_promo_codes + users + vehicle_location_histories + vehicles +(5 rows) ~~~ {% include copy-clipboard.html %} ~~~ sql -> DROP TABLE bank.accounts; +> DROP TABLE users; ~~~ ~~~ -pq: cannot drop table "accounts" because view "user_accounts_view" depends on it +pq: "users" is referenced by foreign key from table "vehicles" ~~~ +To see how `users` is referenced from `vehicles`, you can use the [`SHOW CREATE`](show-create.html) statement. `SHOW CREATE` shows how the columns in a table are created, including data types, default values, indexes, and constraints. + +{% include copy-clipboard.html %} +~~~ sql +> SHOW CREATE TABLE vehicles; +~~~ + +~~~ +table_name | create_statement ++------------+-----------------------------------------------------------------------------------------------+ +vehicles | CREATE TABLE vehicles ( + | id UUID NOT NULL, + | city STRING NOT NULL, + | type STRING NULL, + | owner_id UUID NULL, + | creation_time TIMESTAMP NULL, + | status STRING NULL, + | current_location STRING NULL, + | ext JSONB NULL, + | CONSTRAINT "primary" PRIMARY KEY (city ASC, id ASC), + | CONSTRAINT fk_city_ref_users FOREIGN KEY (city, owner_id) REFERENCES users(city, id), + | INDEX vehicles_auto_index_fk_city_ref_users (city ASC, owner_id ASC), + | FAMILY "primary" (id, city, type, owner_id, creation_time, status, current_location, ext) + | ) +(1 row) +~~~ + + {% include copy-clipboard.html %} ~~~sql -> DROP TABLE bank.accounts CASCADE; +> DROP TABLE users CASCADE; ~~~ ~~~ @@ -116,15 +149,43 @@ DROP TABLE {% include copy-clipboard.html %} ~~~ sql -> SHOW TABLES FROM bank; +> SHOW TABLES FROM movr; ~~~ ~~~ -+------------+ -| table_name | -+------------+ -+------------+ -(0 rows) + table_name ++----------------------------+ + rides + user_promo_codes + vehicle_location_histories + vehicles +(4 rows) +~~~ + +Use a `SHOW CREATE TABLE` statement to verify that the foreign key constraint has been removed from `vehicles`. + +{% include copy-clipboard.html %} +~~~ sql +> SHOW CREATE TABLE vehicles; +~~~ + +~~~ + table_name | create_statement ++------------+-----------------------------------------------------------------------------------------------+ + vehicles | CREATE TABLE vehicles ( + | id UUID NOT NULL, + | city STRING NOT NULL, + | type STRING NULL, + | owner_id UUID NULL, + | creation_time TIMESTAMP NULL, + | status STRING NULL, + | current_location STRING NULL, + | ext JSONB NULL, + | CONSTRAINT "primary" PRIMARY KEY (city ASC, id ASC), + | INDEX vehicles_auto_index_fk_city_ref_users (city ASC, owner_id ASC), + | FAMILY "primary" (id, city, type, owner_id, creation_time, status, current_location, ext) + | ) +(1 row) ~~~ ## See also diff --git a/v19.2/experimental-features.md b/v19.2/experimental-features.md index acdc56b011e..96351f7df70 100644 --- a/v19.2/experimental-features.md +++ b/v19.2/experimental-features.md @@ -108,7 +108,7 @@ Example: Checks the consistency of [`UNIQUE`](unique.html) indexes, [`CHECK`](check.html) constraints, and more. Partially implemented; see [cockroachdb/cockroach#10425](https://github.com/cockroachdb/cockroach/issues/10425) for details. {{site.data.alerts.callout_info}} -This example uses the `users` table from our open-source, fictional peer-to-peer ride-sharing application,[MovR](https://github.com/cockroachdb/movr). +This example uses the `users` table from our open-source, fictional peer-to-peer vehicle-sharing application, [MovR](movr.html). {{site.data.alerts.end}} {% include copy-clipboard.html %} diff --git a/v19.2/indexes.md b/v19.2/indexes.md index 3f0b5d89256..0abc8bb6379 100644 --- a/v19.2/indexes.md +++ b/v19.2/indexes.md @@ -62,7 +62,7 @@ For more information about how to tune CockroachDB's performance, see [SQL Perfo When designing indexes, it's important to consider which columns you index and the order you list them. Here are a few guidelines to help you make the best choices: -- Each table's [primary key](primary-key.html) (which we recommend always [defining](create-table.html#create-a-table-primary-key-defined)) is automatically indexed. The index it creates (called `primary`) cannot be changed, nor can you change the primary key of a table after it's been created, so this is a critical decision for every table. +- Each table's [primary key](primary-key.html) (which we recommend always defining) is automatically indexed. The index it creates (called `primary`) cannot be changed, nor can you change the primary key of a table after it's been created, so this is a critical decision for every table. - Queries can benefit from an index even if they only filter a prefix of its columns. For example, if you create an index of columns `(A, B, C)`, queries filtering `(A)` or `(A, B)` can still use the index. However, queries that do not filter `(A)` will not benefit from the index.

This feature also lets you avoid using single-column indexes. Instead, use the column as the first column in a multiple-column index, which is useful to more queries. - Columns filtered in the `WHERE` clause with the equality operators (`=` or `IN`) should come first in the index, before those referenced with inequality operators (`<`, `>`). - Indexes of the same columns in different orders can produce different results for each query. For more information, see [our blog post on index selection](https://www.cockroachlabs.com/blog/index-selection-cockroachdb-2/)—specifically the section "Restricting the search space." diff --git a/v19.2/insert.md b/v19.2/insert.md index 7ca6f7c1bb2..4aaa36ce059 100644 --- a/v19.2/insert.md +++ b/v19.2/insert.md @@ -67,68 +67,81 @@ key. Using `ON CONFLICT` is therefore more flexible. ## Examples -All of the examples below assume you've already created a table `accounts`: - -{% include copy-clipboard.html %} -~~~ sql -> CREATE TABLE accounts( - id INT DEFAULT unique_rowid() PRIMARY KEY, - balance DECIMAL -); -~~~ +{% include {{page.version.version}}/sql/movr-statements.md %} ### Insert a single row {% include copy-clipboard.html %} ~~~ sql -> INSERT INTO accounts (balance, id) VALUES (10000.50, 1); +> INSERT INTO users VALUES + ('c28f5c28-f5c2-4000-8000-000000000026', 'new york', 'Petee', '101 5th Ave', '1234567890'); ~~~ {% include copy-clipboard.html %} ~~~ sql -> SELECT * FROM accounts; +> SELECT * FROM users WHERE city='new york'; ~~~ ~~~ - id | balance -+----+----------+ - 1 | 10000.50 -(1 row) + id | city | name | address | credit_card ++--------------------------------------+----------+------------------+-----------------------------+-------------+ + 00000000-0000-4000-8000-000000000000 | new york | Robert Murphy | 99176 Anderson Mills | 8885705228 + 051eb851-eb85-4ec0-8000-000000000001 | new york | James Hamilton | 73488 Sydney Ports Suite 57 | 8340905892 + 0a3d70a3-d70a-4d80-8000-000000000002 | new york | Judy White | 18580 Rosario Ville Apt. 61 | 2597958636 + 0f5c28f5-c28f-4c00-8000-000000000003 | new york | Devin Jordan | 81127 Angela Ferry Apt. 8 | 5614075234 + 147ae147-ae14-4b00-8000-000000000004 | new york | Catherine Nelson | 1149 Lee Alley | 0792553487 + c28f5c28-f5c2-4000-8000-000000000026 | new york | Petee | 101 5th Ave | 1234567890 +(6 rows) ~~~ If you do not list column names, the statement will use the columns of the table in their declared order: {% include copy-clipboard.html %} ~~~ sql -> SHOW COLUMNS FROM accounts; +> SHOW COLUMNS FROM users; ~~~ ~~~ column_name | data_type | is_nullable | column_default | generation_expression | indices | is_hidden +-------------+-----------+-------------+----------------+-----------------------+-----------+-----------+ - id | INT8 | false | unique_rowid() | | {primary} | false - balance | DECIMAL | true | NULL | | {} | false -(2 rows) + id | UUID | false | NULL | | {primary} | false + city | STRING | false | NULL | | {primary} | false + name | STRING | true | NULL | | {} | false + address | STRING | true | NULL | | {} | false + credit_card | STRING | true | NULL | | {} | false +(5 rows) ~~~ {% include copy-clipboard.html %} ~~~ sql -> INSERT INTO accounts VALUES (2, 20000.75); +> INSERT INTO users VALUES + ('1eb851eb-851e-4800-8000-000000000006', 'chicago', 'Adam Driver', '201 E Randolph St', '2468013579'); ~~~ {% include copy-clipboard.html %} ~~~ sql -> SELECT * FROM accounts; +> SELECT * FROM users WHERE city IN ('chicago', 'new york'); ~~~ ~~~ - id | balance -+----+----------+ - 1 | 10000.50 - 2 | 20000.75 -(2 rows) + id | city | name | address | credit_card ++--------------------------------------+----------+------------------+--------------------------------+-------------+ + 1eb851eb-851e-4800-8000-000000000006 | chicago | Adam Driver | 201 E Randolph St | 2468013579 + 80000000-0000-4000-8000-000000000019 | chicago | Matthew Clay | 49220 Lisa Junctions | 9132291015 + 851eb851-eb85-4000-8000-00000000001a | chicago | Samantha Coffey | 6423 Jessica Underpass Apt. 87 | 9437219051 + 8a3d70a3-d70a-4000-8000-00000000001b | chicago | Jessica Martinez | 96676 Jennifer Knolls Suite 91 | 1601930189 + 8f5c28f5-c28f-4000-8000-00000000001c | chicago | John Hines | 45229 Howard Manors Suite 22 | 7541086746 + 947ae147-ae14-4800-8000-00000000001d | chicago | Kenneth Barnes | 35627 Chelsey Tunnel Suite 94 | 2099932769 + 00000000-0000-4000-8000-000000000000 | new york | Robert Murphy | 99176 Anderson Mills | 8885705228 + 051eb851-eb85-4ec0-8000-000000000001 | new york | James Hamilton | 73488 Sydney Ports Suite 57 | 8340905892 + 0a3d70a3-d70a-4d80-8000-000000000002 | new york | Judy White | 18580 Rosario Ville Apt. 61 | 2597958636 + 0f5c28f5-c28f-4c00-8000-000000000003 | new york | Devin Jordan | 81127 Angela Ferry Apt. 8 | 5614075234 + 147ae147-ae14-4b00-8000-000000000004 | new york | Catherine Nelson | 1149 Lee Alley | 0792553487 + c28f5c28-f5c2-4000-8000-000000000026 | new york | Petee | 101 5th Ave | 1234567890 +(12 rows) ~~~ + ### Insert multiple rows into an existing table {{site.data.alerts.callout_success}} @@ -137,22 +150,32 @@ Multi-row inserts are faster than multiple single-row `INSERT` statements. As a {% include copy-clipboard.html %} ~~~ sql -> INSERT INTO accounts (id, balance) VALUES (3, 8100.73), (4, 9400.10); +> INSERT INTO users (id, city, name, address, credit_card) VALUES + ('8a3d70a3-d70a-4000-8000-00000000001b', 'seattle', 'Eric', '400 Broad St', '0987654321'), + ('9eb851eb-851e-4800-8000-00000000001f', 'new york', 'Harry Potter', '214 W 43rd St', '5678901234'); ~~~ {% include copy-clipboard.html %} ~~~ sql -> SELECT * FROM accounts; +> SELECT * FROM users WHERE city IN ('seattle', 'new york'); ~~~ ~~~ - id | balance -+----+----------+ - 1 | 10000.50 - 2 | 20000.75 - 3 | 8100.73 - 4 | 9400.10 -(4 rows) + id | city | name | address | credit_card ++--------------------------------------+----------+------------------+-------------------------------+-------------+ + 00000000-0000-4000-8000-000000000000 | new york | Robert Murphy | 99176 Anderson Mills | 8885705228 + 051eb851-eb85-4ec0-8000-000000000001 | new york | James Hamilton | 73488 Sydney Ports Suite 57 | 8340905892 + 0a3d70a3-d70a-4d80-8000-000000000002 | new york | Judy White | 18580 Rosario Ville Apt. 61 | 2597958636 + 0f5c28f5-c28f-4c00-8000-000000000003 | new york | Devin Jordan | 81127 Angela Ferry Apt. 8 | 5614075234 + 147ae147-ae14-4b00-8000-000000000004 | new york | Catherine Nelson | 1149 Lee Alley | 0792553487 + 9eb851eb-851e-4800-8000-00000000001f | new york | Harry Potter | 214 W 43rd St | 5678901234 + c28f5c28-f5c2-4000-8000-000000000026 | new york | Petee | 101 5th Ave | 1234567890 + 428f5c28-f5c2-4000-8000-00000000000d | seattle | Anita Atkinson | 27684 Laura Villages Suite 80 | 9800065169 + 47ae147a-e147-4000-8000-00000000000e | seattle | Patricia Herrera | 80588 Perez Camp | 6812041796 + 4ccccccc-cccc-4c00-8000-00000000000f | seattle | Holly Williams | 95153 Harvey Street Suite 5 | 2165526885 + 51eb851e-b851-4c00-8000-000000000010 | seattle | Ryan Hickman | 21187 Dennis Village | 1635328127 + 8a3d70a3-d70a-4000-8000-00000000001b | seattle | Eric | 400 Broad St | 0987654321 +(12 rows) ~~~ ### Insert multiple rows into a new table @@ -161,96 +184,105 @@ The [`IMPORT`](import.html) statement performs better than `INSERT` when inserti ### Insert from a `SELECT` statement +Suppose that you want MovR to offer ride-sharing services, in addition to vehicle-sharing services. You can create a `drivers` table from a subset of the `users` table. + {% include copy-clipboard.html %} ~~~ sql -> CREATE TABLE other_accounts ( - id INT DEFAULT unique_rowid() PRIMARY KEY, - balance DECIMAL +> CREATE TABLE drivers ( + id UUID DEFAULT gen_random_uuid(), + city STRING, + name STRING, + dl STRING UNIQUE CHECK (LENGTH(dl) < 8), + address STRING, + CONSTRAINT "primary" PRIMARY KEY (city ASC, id ASC) ); ~~~ {% include copy-clipboard.html %} ~~~ sql -> INSERT INTO other_accounts (id, balance) VALUES (5, 350.10), (6, 150), (7, 200.10); +> INSERT INTO drivers (id, city, name, address) + SELECT id, city, name, address FROM users + WHERE name IN ('Anita Atkinson', 'Devin Jordan'); ~~~ {% include copy-clipboard.html %} ~~~ sql -> INSERT INTO accounts (id, balance) SELECT id, balance FROM other_accounts WHERE id > 4; +> SELECT * FROM drivers; ~~~ +~~~ + id | city | name | dl | address ++--------------------------------------+----------+----------------+------+-------------------------------+ + 0f5c28f5-c28f-4c00-8000-000000000003 | new york | Devin Jordan | NULL | 81127 Angela Ferry Apt. 8 + 428f5c28-f5c2-4000-8000-00000000000d | seattle | Anita Atkinson | NULL | 27684 Laura Villages Suite 80 +(2 rows) +~~~ + +### Insert default values + +To check the [default values](default-value.html) for columns in a table, use the [`SHOW CREATE TABLE`](show-create.html) statement: + {% include copy-clipboard.html %} ~~~ sql -> SELECT * FROM accounts; +> SHOW CREATE TABLE drivers; ~~~ ~~~ - id | balance -+----+----------+ - 1 | 10000.50 - 2 | 20000.75 - 3 | 8100.73 - 4 | 9400.10 - 5 | 350.10 - 6 | 150 - 7 | 200.10 -(7 rows) + table_name | create_statement ++------------+----------------------------------------------------------+ + drivers | CREATE TABLE drivers ( + | id UUID NOT NULL DEFAULT gen_random_uuid(), + | city STRING NOT NULL, + | name STRING NULL, + | dl STRING NULL, + | address STRING NULL, + | CONSTRAINT "primary" PRIMARY KEY (city ASC, id ASC), + | UNIQUE INDEX drivers_dl_key (dl ASC), + | FAMILY "primary" (id, city, name, dl, address), + | CONSTRAINT check_dl CHECK (length(dl) < 8) + | ) +(1 row) ~~~ -### Insert default values +If the `DEFAULT` value constraint is not specified and an explicit value is not given, a value of *NULL* is assigned to the column. {% include copy-clipboard.html %} ~~~ sql -> INSERT INTO accounts (id) VALUES (8); +> INSERT INTO drivers (city, name) VALUES ('seattle', 'Bobby'); ~~~ {% include copy-clipboard.html %} ~~~ sql -> INSERT INTO accounts (id, balance) VALUES (9, DEFAULT); +> INSERT INTO drivers (city, name, id) VALUES ('chicago', 'Terry', DEFAULT); ~~~ {% include copy-clipboard.html %} ~~~ sql -> SELECT * FROM accounts WHERE id in (8, 9); +> SELECT * FROM drivers WHERE name in ('Bobby', 'Terry'); ~~~ ~~~ - id | balance -+----+---------+ - 8 | NULL - 9 | NULL + id | city | name | dl | address ++--------------------------------------+---------+-------+------+---------+ + c8d36f0e-9eb4-439f-b3d0-029af184d24b | chicago | Terry | NULL | NULL + af2e8122-bf87-4736-bde9-a42ad0857351 | seattle | Bobby | NULL | NULL (2 rows) ~~~ -{% include copy-clipboard.html %} -~~~ sql -> INSERT INTO accounts DEFAULT VALUES; -~~~ +To create a new row with only default values, use `INSERT INTO DEFAULT VALUES`. Running this command on the `drivers` table results in an error because the `city` column in `drivers` cannot be *NULL*, and has no default value specified. {% include copy-clipboard.html %} ~~~ sql -> SELECT * FROM accounts; +> INSERT INTO drivers DEFAULT VALUES; ~~~ ~~~ - id | balance -+--------------------+----------+ - 1 | 10000.50 - 2 | 20000.75 - 3 | 8100.73 - 4 | 9400.10 - 5 | 350.10 - 6 | 150 - 7 | 200.10 - 8 | NULL - 9 | NULL - 454320296521498625 | NULL -(10 rows) +pq: null value in column "city" violates not-null constraint ~~~ ### Insert and return values -In this example, the `RETURNING` clause returns the `id` values of the rows inserted, which are generated server-side by the `unique_rowid()` function. The language-specific versions assume that you have installed the relevant [client drivers](install-client-drivers.html). +In this example, the `RETURNING` clause returns the `id` values of the rows inserted, which are generated server-side by the `gen_random_uuid()` function. The language-specific versions assume that you have installed the relevant [client drivers](install-client-drivers.html). {{site.data.alerts.callout_success}}This use of RETURNING mirrors the behavior of MySQL's last_insert_id() function.{{site.data.alerts.end}} @@ -268,16 +300,16 @@ In this example, the `RETURNING` clause returns the `id` values of the rows inse {% include copy-clipboard.html %} ~~~ sql -> INSERT INTO accounts (id, balance) - VALUES (DEFAULT, 1000), (DEFAULT, 250) +> INSERT INTO drivers (id, city) + VALUES (DEFAULT, 'seattle'), (DEFAULT, 'chicago') RETURNING id; ~~~ ~~~ - id -+--------------------+ - 454320445012049921 - 454320445012082689 + id ++--------------------------------------+ + b7750a60-91f2-404e-9cd1-5a3c310c1c9d + c85e637e-2b03-4a52-bc54-1e1f6d7fd89b (2 rows) ~~~ @@ -290,9 +322,9 @@ In this example, the `RETURNING` clause returns the `id` values of the rows inse # Import the driver. import psycopg2 -# Connect to the "bank" database. +# Connect to the "movr" database. conn = psycopg2.connect( - database='bank', + database='movr', user='root', host='localhost', port=26257 @@ -304,12 +336,12 @@ conn.set_session(autocommit=True) # Open a cursor to perform database operations. cur = conn.cursor() -# Insert two rows into the "accounts" table +# Insert two rows into the "drivers" table # and return the "id" values generated server-side. cur.execute( - 'INSERT INTO accounts (id, balance) ' - 'VALUES (DEFAULT, 1000), (DEFAULT, 250) ' - 'RETURNING id' + "INSERT INTO drivers (id, city) " + "VALUES (DEFAULT, 'seattle'), (DEFAULT, 'chicago') " + "RETURNING id" ) # Print out the returned values. @@ -327,8 +359,8 @@ The printed values would look like: ~~~ IDs: -['190019066706952193'] -['190019066706984961'] +['cdd379e3-2d0b-4622-8ba8-4f0a1edfbc8e'] +['4224b360-b1b0-4e4d-aba2-a35c64cdf404'] ~~~ @@ -340,20 +372,20 @@ IDs: # Import the driver. require 'pg' -# Connect to the "bank" database. +# Connect to the "movr" database. conn = PG.connect( user: 'root', - dbname: 'bank', + dbname: 'movr', host: 'localhost', port: 26257 ) -# Insert two rows into the "accounts" table +# Insert two rows into the "drivers" table # and return the "id" values generated server-side. conn.exec( - 'INSERT INTO accounts (id, balance) '\ - 'VALUES (DEFAULT, 1000), (DEFAULT, 250) '\ - 'RETURNING id' + "INSERT INTO drivers (id, city) "\ + "VALUES (DEFAULT, 'seattle'), (DEFAULT, 'chicago') "\ + "RETURNING id" ) do |res| # Print out the returned values. @@ -371,8 +403,8 @@ The printed values would look like: ~~~ IDs: -{"id"=>"190019066706952193"} -{"id"=>"190019066706984961"} +{"id"=>"cdd379e3-2d0b-4622-8ba8-4f0a1edfbc8e"} +{"id"=>"4224b360-b1b0-4e4d-aba2-a35c64cdf404"} ~~~ @@ -384,44 +416,44 @@ IDs: package main import ( - "database/sql" - "fmt" - "log" + "database/sql" + "fmt" + "log" - _ "github.com/lib/pq" + _ "github.com/lib/pq" ) func main() { - //Connect to the "bank" database. - db, err := sql.Open( - "postgres", - "postgresql://root@localhost:26257/bank?sslmode=disable" - ) - if err != nil { - log.Fatal("error connecting to the database: ", err) - } - - // Insert two rows into the "accounts" table - // and return the "id" values generated server-side. - rows, err := db.Query( - "INSERT INTO accounts (id, balance) " + - "VALUES (DEFAULT, 1000), (DEFAULT, 250) " + - "RETURNING id", - ) - if err != nil { - log.Fatal(err) - } - - // Print out the returned values. - defer rows.Close() - fmt.Println("IDs:") - for rows.Next() { - var id int - if err := rows.Scan(&id); err != nil { - log.Fatal(err) - } - fmt.Printf("%d\n", id) - } + //Connect to the "movr" database. + db, err := sql.Open( + "postgres", + "postgresql://root@localhost:26257/movr?sslmode=disable", + ) + if err != nil { + log.Fatal("error connecting to the database: ", err) + } + + // Insert two rows into the "drivers" table + // and return the "id" values generated server-side. + rows, err := db.Query( + "INSERT INTO drivers (id, city) " + + "VALUES (DEFAULT, 'seattle'), (DEFAULT, 'chicago') " + + "RETURNING id", + ) + if err != nil { + log.Fatal(err) + } + + // Print out the returned values. + defer rows.Close() + fmt.Println("IDs:") + for rows.Next() { + var id string + if err := rows.Scan(&id); err != nil { + log.Fatal(err) + } + fmt.Printf("%s\n", id) + } } ~~~ @@ -429,8 +461,8 @@ The printed values would look like: ~~~ IDs: -190019066706952193 -190019066706984961 +cdd379e3-2d0b-4622-8ba8-4f0a1edfbc8e +4224b360-b1b0-4e4d-aba2-a35c64cdf404 ~~~ @@ -439,89 +471,91 @@ IDs: {% include copy-clipboard.html %} ~~~ js -var async = require('async'); - -// Require the driver. -var pg = require('pg'); +var async = require('async') +var pg = require('pg') -// Connect to the "bank" database. +// Config to connect to the "movr" database. var config = { - user: 'root', - host: 'localhost', - database: 'bank', - port: 26257 -}; - -pg.connect(config, function (err, client, done) { - // Closes communication with the database and exits. - var finish = function () { - done(); - process.exit(); - }; - - if (err) { - console.error('could not connect to cockroachdb', err); - finish(); + user: 'root', + host: 'localhost', + database: 'movr', + port: 26257 } + +// Create pool +var pool = new pg.Pool(config) + +pool.connect(function (err, client, done) { + + // Close communication with the database and exit. + var finish = function () { + done() + process.exit() + } + + if (err) { + console.error('could not connect to cockroachdb', err) + finish() + } async.waterfall([ function (next) { - // Insert two rows into the "accounts" table + // Insert two rows into the "drivers" table // and return the "id" values generated server-side. client.query( - `INSERT INTO accounts (id, balance) - VALUES (DEFAULT, 1000), (DEFAULT, 250) - RETURNING id;`, + `INSERT INTO drivers (id, city) + VALUES (DEFAULT, 'seattle'), (DEFAULT, 'chicago') + RETURNING id`, next - ); + ) } ], function (err, results) { if (err) { - console.error('error inserting into and selecting from accounts', err); - finish(); + console.error('error inserting into and selecting from drivers', err) + finish() } // Print out the returned values. - console.log('IDs:'); + console.log('IDs:') results.rows.forEach(function (row) { - console.log(row); - }); + console.log(row) + }) - finish(); - }); -}); + finish() + }) +}) ~~~ The printed values would look like: ~~~ IDs: -{ id: '190019066706952193' } -{ id: '190019066706984961' } +{ id: 'cdd379e3-2d0b-4622-8ba8-4f0a1edfbc8e' } +{ id: '4224b360-b1b0-4e4d-aba2-a35c64cdf404' } ~~~ ### Update values `ON CONFLICT` -When a uniqueness conflict is detected, CockroachDB stores the row in a temporary table called `excluded`. This example demonstrates how you use the columns in the temporary `excluded` table to apply updates on conflict: +When a uniqueness conflict is detected, CockroachDB stores the row in a temporary table called `excluded`. This example demonstrates how you use the columns in the temporary `excluded` table to apply updates on conflict. {% include copy-clipboard.html %} ~~~ sql -> INSERT INTO accounts (id, balance) - VALUES (8, 500.50) - ON CONFLICT (id) - DO UPDATE SET balance = excluded.balance; +> INSERT INTO user_promo_codes (city, user_id, code, "timestamp", usage_count) + VALUES ('new york', '147ae147-ae14-4b00-8000-000000000004', 'promo_code', now(), 1) + ON CONFLICT (city, user_id, code) + DO UPDATE SET usage_count = excluded.usage_count; ~~~ {% include copy-clipboard.html %} ~~~ sql -> SELECT * FROM accounts WHERE id = 8; +> SELECT * FROM user_promo_codes WHERE code = 'promo_code'; ~~~ ~~~ - id | balance -+----+---------+ - 8 | 500.50 + city | user_id | code | timestamp | usage_count ++----------+--------------------------------------+------------+----------------------------------+-------------+ + new york | 147ae147-ae14-4b00-8000-000000000004 | promo_code | 2019-08-12 14:23:52.262849+00:00 | 1 (1 row) ~~~ @@ -529,21 +563,21 @@ You can also update the row using an existing value: {% include copy-clipboard.html %} ~~~ sql -> INSERT INTO accounts (id, balance) - VALUES (8, 500.50) - ON CONFLICT (id) - DO UPDATE SET balance = accounts.balance + excluded.balance; +> INSERT INTO user_promo_codes (city, user_id, code, "timestamp", usage_count) + VALUES ('new york', '147ae147-ae14-4b00-8000-000000000004', 'promo_code', now(), 1) + ON CONFLICT (city, user_id, code) + DO UPDATE SET ("timestamp", usage_count) = (now(), user_promo_codes.usage_count + excluded.usage_count); ~~~ {% include copy-clipboard.html %} ~~~ sql -> SELECT * FROM accounts WHERE id = 8; +> SELECT * FROM user_promo_codes WHERE code = 'promo_code'; ~~~ ~~~ - id | balance -+----+---------+ - 8 | 1001.00 + city | user_id | code | timestamp | usage_count ++----------+--------------------------------------+------------+----------------------------------+-------------+ + new york | 147ae147-ae14-4b00-8000-000000000004 | promo_code | 2019-08-12 14:26:50.697382+00:00 | 2 (1 row) ~~~ @@ -551,69 +585,58 @@ You can also use a `WHERE` clause to apply the `DO UPDATE SET` expression condit {% include copy-clipboard.html %} ~~~ sql -> INSERT INTO accounts (id, balance) - VALUES (8, 700) - ON CONFLICT (id) - DO UPDATE SET balance = excluded.balance - WHERE excluded.balance > accounts.balance; +> INSERT INTO user_promo_codes (city, user_id, code, "timestamp", usage_count) + VALUES ('new york', '147ae147-ae14-4b00-8000-000000000004', 'promo_code', now(), 3) + ON CONFLICT (city, user_id, code) + DO UPDATE SET ("timestamp", usage_count) = (now(), user_promo_codes.usage_count + excluded.usage_count) + WHERE excluded.usage_count = 1; ~~~ {% include copy-clipboard.html %} ~~~ sql -> SELECT * FROM accounts WHERE id = 8; +> SELECT * FROM user_promo_codes WHERE code = 'promo_code'; ~~~ ~~~ - id | balance -+----+---------+ - 8 | 800.00 + city | user_id | code | timestamp | usage_count ++----------+--------------------------------------+------------+----------------------------------+-------------+ + new york | 147ae147-ae14-4b00-8000-000000000004 | promo_code | 2019-08-12 14:26:50.697382+00:00 | 2 (1 row) ~~~ ### Do not update values `ON CONFLICT` -In this example, we get an error from a uniqueness conflict: - -{% include copy-clipboard.html %} -~~~ sql -> SELECT * FROM accounts WHERE id = 8; -~~~ - -~~~ - id | balance -+----+---------+ - 8 | 1001.00 -(1 row) -~~~ +In this example, we get an error from a uniqueness conflict. {% include copy-clipboard.html %} ~~~ sql -> INSERT INTO accounts (id, balance) VALUES (8, 125.50); +> INSERT INTO user_promo_codes (city, user_id, code, "timestamp", usage_count) + VALUES ('new york', '147ae147-ae14-4b00-8000-000000000004', 'promo_code', now(), 1); ~~~ ~~~ -pq: duplicate key value (id)=(8) violates unique constraint "primary" +pq: duplicate key value (city,user_id,code)=('new york','147ae147-ae14-4b00-8000-000000000004','promo_code') violates unique constraint "primary" ~~~ In this example, we use `ON CONFLICT DO NOTHING` to ignore the uniqueness error and prevent the affected row from being updated: {% include copy-clipboard.html %} ~~~ sql -> INSERT INTO accounts (id, balance) - VALUES (8, 125.50) - ON CONFLICT (id) +> INSERT INTO user_promo_codes (city, user_id, code, "timestamp", usage_count) + VALUES ('new york', '147ae147-ae14-4b00-8000-000000000004', 'promo_code', now(), 1) + ON CONFLICT (city, user_id, code) DO NOTHING; ~~~ {% include copy-clipboard.html %} ~~~ sql -> SELECT * FROM accounts WHERE id = 8; +> SELECT * FROM user_promo_codes WHERE code = 'promo_code'; ~~~ ~~~ - id | balance -+----+---------+ - 8 | 1001.00 + city | user_id | code | timestamp | usage_count ++----------+--------------------------------------+------------+----------------------------------+-------------+ + new york | 147ae147-ae14-4b00-8000-000000000004 | promo_code | 2019-08-12 14:26:50.697382+00:00 | 2 (1 row) ~~~ @@ -621,22 +644,22 @@ In this example, `ON CONFLICT DO NOTHING` prevents the first row from updating w {% include copy-clipboard.html %} ~~~ sql -> INSERT INTO accounts (id, balance) - VALUES (8, 125.50), (10, 450) - ON CONFLICT (id) +> INSERT INTO user_promo_codes (city, user_id, code, "timestamp", usage_count) + VALUES ('new york', '147ae147-ae14-4b00-8000-000000000004', 'promo_code', now(), 1), ('new york', '147ae147-ae14-4b00-8000-000000000004', 'new_promo', now(), 1) + ON CONFLICT (city, user_id, code) DO NOTHING; ~~~ {% include copy-clipboard.html %} ~~~ sql -> SELECT * FROM accounts WHERE id in (8, 10); +> SELECT * FROM user_promo_codes WHERE code in ('promo_code', 'new_promo'); ~~~ ~~~ - id | balance -+----+---------+ - 8 | 1001.00 - 10 | 450 + city | user_id | code | timestamp | usage_count ++----------+--------------------------------------+------------+----------------------------------+-------------+ + new york | 147ae147-ae14-4b00-8000-000000000004 | new_promo | 2019-08-12 14:30:16.666848+00:00 | 1 + new york | 147ae147-ae14-4b00-8000-000000000004 | promo_code | 2019-08-12 14:26:50.697382+00:00 | 2 (2 rows) ~~~ @@ -651,13 +674,11 @@ For example: {% include copy-clipboard.html %} ~~~ sql -> WITH - -- the following data contains duplicates on the conflict column "id": - inputrows AS (VALUES (8, 130), (8, 140)) - - INSERT INTO accounts (id, balance) - (SELECT DISTINCT ON(id) id, balance FROM inputrows) -- de-duplicate the input rows - ON CONFLICT (id) +> WITH inputrows (city, user_id, code, "timestamp", usage_count) + AS (VALUES ('new york', '147ae147-ae14-4b00-8000-000000000004'::uuid, 'promo_code', now()::timestamp, 0), ('new york', '147ae147-ae14-4b00-8000-000000000004'::uuid, 'new_promo', now()::timestamp, 2)) + INSERT INTO user_promo_codes (city, user_id, code, "timestamp", usage_count) + (SELECT DISTINCT ON(city, user_id, code) * FROM inputrows) + ON CONFLICT (city, user_id, code) DO NOTHING; ~~~ @@ -667,15 +688,11 @@ considered. To force the selection of a particular duplicate, use an {% include copy-clipboard.html %} ~~~ sql -> WITH - -- the following data contains duplicates on the conflict column "id": - inputrows AS (VALUES (8, 130), (8, 140)) - - INSERT INTO accounts (id, balance) - (SELECT DISTINCT ON(id) id, balance - FROM inputrows - ORDER BY balance) -- pick the lowest balance as value to update in each account - ON CONFLICT (id) +> WITH inputrows (city, user_id, code, "timestamp", usage_count) + AS (VALUES ('new york', '147ae147-ae14-4b00-8000-000000000004'::uuid, 'promo_code', now()::timestamp, 0), ('new york', '147ae147-ae14-4b00-8000-000000000004'::uuid, 'new_promo', now()::timestamp, 2)) + INSERT INTO user_promo_codes (city, user_id, code, "timestamp", usage_count) + (SELECT DISTINCT ON(city, user_id, code) * FROM inputrows ORDER BY (city, user_id, code, usage_count)) + ON CONFLICT (city, user_id, code) DO NOTHING; ~~~ diff --git a/v19.2/movr.md b/v19.2/movr.md new file mode 100644 index 00000000000..e846730059d --- /dev/null +++ b/v19.2/movr.md @@ -0,0 +1,93 @@ +--- +title: MovR +summary: The MovR application uses CockroachDB to store information about vehicles, users, and rides. +toc: true +--- + +MovR is a fictional vehicle-sharing company created to demonstrate CockroachDB's features. + +## Overview + +The MovR example consists of the following: + +- The `movr` dataset, which contains of rows of data that populate tables in the `movr` database. The `movr` dataset is built into [`cockroach demo`](cockroach-demo.html) and [`cockroach workload`](cockroach-workload.html). +- The MovR application, a fully-functional vehicle-sharing application, written in Python. All of MovR application source code is open-source, and available on the [movr](https://github.com/cockroachdb/movr) GitHub repository. + +## The `movr` database + +Six tables in the `movr` database store user, vehicle, and ride data for MovR: + +Table | Description +--------|---------------------------- +`users` | People registered for the service. +`vehicles` | The pool of vehicles available for the service. +`rides` | When and where users have rented a vehicle. +`promo_codes` | Promotional codes for users. +`user_promo_codes` | Promotional codes in use by users. +`vehicle_location_histories` | Vehicle location history. + + + +## Generating schemas and data for MovR + +Use the following `cockroach` commands to load the `movr` database and dataset that are built into the CockroachDB binary: + +- [`cockroach demo movr`](cockroach-demo.html) opens a temporary, in-memory cluster with the `movr` database preloaded and set as the [current database](sql-name-resolution.html#current-database). + +- [`cockroach workload init movr`](cockroach-workload.html) loads the `movr` database and some sample data to a running cluster. + +## How the MovR application works + +The following steps summarize how the MovR application works: + +1. A user loads the app and sees the 25 closest vehicles. Behind the scenes, this is a `SELECT` from the `vehicles` table: + + ~~~ sql + > SELECT id, city, status, ... FROM vehicles WHERE city = + ~~~ + +2. The user signs up for the service, which is an `INSERT` of a row into the `users` table: + + ~~~ sql + > INSERT INTO users (id, name, address, ...) VALUES ... + ~~~ + +3. In some cases, the user adds their own vehicle to share, which is an `INSERT` of a row into the `vehicles` table: + + ~~~ sql + > INSERT INTO vehicles (id, city, type, ...) VALUES ... + ~~~ + +4. More often, the user reserves a vehicle and starts a ride, which is an `UPDATE` of a row in the `vehicles` table and an `INSERT` of a row into the `rides` table: + + ~~~ sql + > UPDATE vehicles SET status = 'in_use' WHERE ... + ~~~ + + ~~~ sql + > INSERT INTO rides (id, city, start_addr, ...) VALUES ... + ~~~ + +5. The user ends the ride and releases the vehicle, which is an `UPDATE` of a row in the `vehicles` table and an `UPDATE` of a row in the `rides` table: + + ~~~ sql + > UPDATE vehicles SET status = 'available' WHERE ... + ~~~ + + ~~~ sql + > UPDATE rides SET end_address = ... + ~~~ + +## Extended examples + +MovR scales as a geo-partitioned application and database that you can deploy using Docker images across a multi-region cluster deployment. + +For a tutorial about geo-partitioning for fast reads and writes, see [Geo-Partitioning for Fast Reads and Writes in a Multi-Region Cluster](demo-geo-partitioning.html). + +For a tutorial about performance tuning in CockroachDB, see [Performance Tuning](performance-tuning.html). + +## See also + +- [Learn CockroachDB SQL](learn-cockroachdb-sql.html) +- [Build an App with CockroachDB](build-an-app-with-cockroachdb.html) +- [Experimental Features](experimental-features.html) diff --git a/v19.2/select-clause.md b/v19.2/select-clause.md index 34190aa5a3b..e745791792b 100644 --- a/v19.2/select-clause.md +++ b/v19.2/select-clause.md @@ -60,6 +60,8 @@ using the [scalar expressions](scalar-expressions.html) listed with `ON`. When t ## Examples +{% include {{page.version.version}}/sql/movr-statements.md %} + ### Choose columns #### Retrieve specific columns @@ -68,19 +70,23 @@ Retrieve specific columns by naming them in a comma-separated list: {% include copy-clipboard.html %} ~~~ sql -> SELECT id, name, balance -FROM accounts; +> SELECT id, city, name FROM users LIMIT 10; ~~~ ~~~ -+----+-----------------------+---------+ -| id | name | balance | -+----+-----------------------+---------+ -| 1 | Bjorn Fairclough | 1200 | -| 2 | Bjorn Fairclough | 2500 | -| 3 | Arturo Nevin | 250 | -[ truncated ] -+----+-----------------------+---------+ + id | city | name ++--------------------------------------+---------------+------------------+ + 7ae147ae-147a-4000-8000-000000000018 | los angeles | Alfred Garcia + 570a3d70-a3d7-4c00-8000-000000000011 | san francisco | Amy Cobb + 428f5c28-f5c2-4000-8000-00000000000d | seattle | Anita Atkinson + 1eb851eb-851e-4800-8000-000000000006 | boston | Brian Campbell + 23d70a3d-70a3-4800-8000-000000000007 | boston | Carl Mcguire + a8f5c28f-5c28-4800-8000-000000000021 | detroit | Carl Russell + 147ae147-ae14-4b00-8000-000000000004 | new york | Catherine Nelson + 99999999-9999-4800-8000-00000000001e | detroit | Charles Montoya + e147ae14-7ae1-4800-8000-00000000002c | paris | Cheyenne Smith + 2e147ae1-47ae-4400-8000-000000000009 | washington dc | Cindy Medina +(10 rows) ~~~ #### Retrieve all columns @@ -89,19 +95,23 @@ Retrieve all columns by using `*`: {% include copy-clipboard.html %} ~~~ sql -> SELECT * -FROM accounts; +> SELECT * FROM users LIMIT 10; ~~~ ~~~ -+----+-----------------------+---------+----------+--------------+ -| id | name | balance | type | state_opened | -+----+-----------------------+---------+----------+--------------+ -| 1 | Bjorn Fairclough | 1200 | checking | AL | -| 2 | Bjorn Fairclough | 2500 | savings | AL | -| 3 | Arturo Nevin | 250 | checking | AK | -[ truncated ] -+----+-----------------------+---------+----------+--------------+ + id | city | name | address | credit_card ++--------------------------------------+-----------+--------------------+--------------------------------+-------------+ + c28f5c28-f5c2-4000-8000-000000000026 | amsterdam | Maria Weber | 14729 Karen Radial | 5844236997 + c7ae147a-e147-4000-8000-000000000027 | amsterdam | Tina Miller | 97521 Mark Extensions | 8880478663 + cccccccc-cccc-4000-8000-000000000028 | amsterdam | Taylor Cunningham | 89214 Jennifer Well | 5130593761 + d1eb851e-b851-4800-8000-000000000029 | amsterdam | Kimberly Alexander | 48474 Alfred Hollow | 4059628542 + 19999999-9999-4a00-8000-000000000005 | boston | Nicole Mcmahon | 11540 Patton Extensions | 0303726947 + 1eb851eb-851e-4800-8000-000000000006 | boston | Brian Campbell | 92025 Yang Village | 9016427332 + 23d70a3d-70a3-4800-8000-000000000007 | boston | Carl Mcguire | 60124 Palmer Mews Apt. 49 | 4566257702 + 28f5c28f-5c28-4600-8000-000000000008 | boston | Jennifer Sanders | 19121 Padilla Brooks Apt. 12 | 1350968125 + 80000000-0000-4000-8000-000000000019 | chicago | Matthew Clay | 49220 Lisa Junctions | 9132291015 + 851eb851-eb85-4000-8000-00000000001a | chicago | Samantha Coffey | 6423 Jessica Underpass Apt. 87 | 9437219051 +(10 rows) ~~~ ### Filter rows @@ -112,19 +122,17 @@ Filter rows with expressions that use columns and return Boolean values in the ` {% include copy-clipboard.html %} ~~~ sql -> SELECT name, balance -FROM accounts -WHERE balance < 300; +> SELECT name, id FROM users WHERE city='seattle'; ~~~ ~~~ -+------------------+---------+ -| name | balance | -+------------------+---------+ -| Arturo Nevin | 250 | -| Akbar Jinks | 250 | -| Andrea Maas | 250 | -+------------------+---------+ + name | id ++------------------+--------------------------------------+ + Anita Atkinson | 428f5c28-f5c2-4000-8000-00000000000d + Patricia Herrera | 47ae147a-e147-4000-8000-00000000000e + Holly Williams | 4ccccccc-cccc-4c00-8000-00000000000f + Ryan Hickman | 51eb851e-b851-4c00-8000-000000000010 +(4 rows) ~~~ #### Filter on multiple conditions @@ -133,78 +141,86 @@ To use multiple `WHERE` filters join them with `AND` or `OR`. You can also creat {% include copy-clipboard.html %} ~~~ sql -> SELECT * -FROM accounts -WHERE balance > 2500 AND NOT type = 'checking'; +> SELECT * FROM vehicles WHERE city = 'seattle' AND status = 'available'; ~~~ ~~~ -+----+-------------------+---------+---------+--------------+ -| id | name | balance | type | state_opened | -+----+-------------------+---------+---------+--------------+ -| 4 | Tullia Romijnders | 3000 | savings | AK | -| 62 | Ruarc Mathews | 3000 | savings | OK | -+----+-------------------+---------+---------+--------------+ + id | city | type | owner_id | creation_time | status | current_location | ext ++--------------------------------------+---------+------+--------------------------------------+---------------------------+-----------+------------------------+----------------------------------------+ + 44444444-4444-4400-8000-000000000004 | seattle | bike | 428f5c28-f5c2-4000-8000-00000000000d | 2019-01-02 03:04:05+00:00 | available | 37754 Farmer Extension | {"brand": "Merida", "color": "yellow"} +(1 row) ~~~ -#### Select distinct rows +#### Filter values with a list -Columns without the [Primary Key](primary-key.html) or [Unique](unique.html) constraints can have multiple instances of the same value: +Using `WHERE IN ()` performs an `OR` search for listed values in the specified column: {% include copy-clipboard.html %} ~~~ sql -> SELECT name -FROM accounts -WHERE state_opened = 'VT'; +> SELECT name, id FROM users WHERE city IN ('new york', 'chicago', 'seattle'); ~~~ ~~~ -+----------------+ -| name | -+----------------+ -| Sibylla Malone | -| Sibylla Malone | -+----------------+ + name | id ++------------------+--------------------------------------+ + Matthew Clay | 80000000-0000-4000-8000-000000000019 + Samantha Coffey | 851eb851-eb85-4000-8000-00000000001a + Jessica Martinez | 8a3d70a3-d70a-4000-8000-00000000001b + John Hines | 8f5c28f5-c28f-4000-8000-00000000001c + Kenneth Barnes | 947ae147-ae14-4800-8000-00000000001d + Robert Murphy | 00000000-0000-4000-8000-000000000000 + James Hamilton | 051eb851-eb85-4ec0-8000-000000000001 + Judy White | 0a3d70a3-d70a-4d80-8000-000000000002 + Devin Jordan | 0f5c28f5-c28f-4c00-8000-000000000003 + Catherine Nelson | 147ae147-ae14-4b00-8000-000000000004 + Anita Atkinson | 428f5c28-f5c2-4000-8000-00000000000d + Patricia Herrera | 47ae147a-e147-4000-8000-00000000000e + Holly Williams | 4ccccccc-cccc-4c00-8000-00000000000f + Ryan Hickman | 51eb851e-b851-4c00-8000-000000000010 +(14 rows) ~~~ -Using `DISTINCT`, you can remove all but one instance of duplicate values from your retrieved data: +#### Select distinct rows + +Columns without the [Primary Key](primary-key.html) or [Unique](unique.html) constraints can have multiple instances of the same value: {% include copy-clipboard.html %} ~~~ sql -> SELECT DISTINCT name -FROM accounts -WHERE state_opened = 'VT'; +> SELECT name FROM users WHERE city in ('los angeles', 'washington dc'); ~~~ ~~~ -+----------------+ -| name | -+----------------+ -| Sibylla Malone | -+----------------+ + name ++---------------------+ + Ricky Beck + Michael Brown + William Wood + Alfred Garcia + Cindy Medina + Daniel Hernandez MD + Sarah Wang DDS + Michael Brown +(8 rows) ~~~ -#### Filter values with a list - -Using `WHERE IN ()` performs an `OR` search for listed values in the specified column: +Using `DISTINCT`, you can remove all but one instance of duplicate values from your retrieved data: {% include copy-clipboard.html %} ~~~ sql -> SELECT name, balance, state_opened -FROM accounts -WHERE state_opened IN ('AZ', 'NY', 'WA'); +> SELECT DISTINCT name FROM users WHERE city in ('los angeles', 'washington dc'); ~~~ ~~~ -+-----------------+---------+--------------+ -| name | balance | state_opened | -+-----------------+---------+--------------+ -| Naseem Joossens | 300 | AZ | -| Aygün Sanna | 900 | NY | -| Carola Dahl | 800 | NY | -| Edna Barath | 750 | WA | -| Edna Barath | 2200 | WA | -+-----------------+---------+--------------+ + name ++---------------------+ + Ricky Beck + Michael Brown + William Wood + Alfred Garcia + Cindy Medina + Daniel Hernandez MD + Sarah Wang DDS +(7 rows) ~~~ ### Rename columns in output @@ -213,18 +229,15 @@ Instead of outputting a column's name in the retrieved table, you can change its {% include copy-clipboard.html %} ~~~ sql -> SELECT name AS NY_accounts, balance -FROM accounts -WHERE state_opened = 'NY'; +> SELECT current_location AS ny_address, id, type, status FROM vehicles WHERE city = 'new york'; ~~~ ~~~ -+-------------+---------+ -| NY_accounts | balance | -+-------------+---------+ -| Aygün Sanna | 900 | -| Carola Dahl | 800 | -+-------------+---------+ + ny_address | id | type | status ++------------------------+--------------------------------------+------------+--------+ + 64110 Richard Crescent | 00000000-0000-4000-8000-000000000000 | skateboard | in_use + 86667 Edwards Valley | 11111111-1111-4100-8000-000000000001 | scooter | in_use +(2 rows) ~~~ This *does not* change the name of the column in the table. To do that, use [`RENAME COLUMN`](rename-column.html). @@ -240,18 +253,20 @@ For example: {% include copy-clipboard.html %} ~~~ sql -> SELECT id, name, type -FROM accounts -WHERE name LIKE 'Anni%'; +> SELECT city, status, id FROM vehicles WHERE type LIKE 'scoot%'; ~~~ ~~~ -+----+----------------+----------+ -| id | name | type | -+----+----------------+----------+ -| 58 | Annibale Karga | checking | -| 59 | Annibale Karga | savings | -+----+----------------+----------+ + city | status | id ++---------------+-----------+--------------------------------------+ + boston | in_use | 22222222-2222-4200-8000-000000000002 + detroit | in_use | 99999999-9999-4800-8000-000000000009 + minneapolis | in_use | aaaaaaaa-aaaa-4800-8000-00000000000a + minneapolis | available | bbbbbbbb-bbbb-4800-8000-00000000000b + new york | in_use | 11111111-1111-4100-8000-000000000001 + san francisco | available | 55555555-5555-4400-8000-000000000005 + washington dc | in_use | 33333333-3333-4400-8000-000000000003 +(7 rows) ~~~ ### Aggregate functions @@ -264,40 +279,41 @@ By using an aggregate function as a `target_elem`, you can perform the calculati {% include copy-clipboard.html %} ~~~ sql -> SELECT MIN(balance) -FROM accounts; +> SELECT MIN(revenue) FROM rides; ~~~ ~~~ -+--------------+ -| MIN(balance) | -+--------------+ -| 250 | -+--------------+ + min ++------+ + 0.00 +(1 row) ~~~ You can also use the retrieved value as part of an expression. For example, you can use the result in the `WHERE` clause to select additional rows that were not part of the aggregate function itself: {% include copy-clipboard.html %} ~~~ sql -> SELECT id, name, balance -FROM accounts -WHERE balance = ( +> SELECT id, city, vehicle_id, rider_id +FROM rides +WHERE revenue = ( SELECT - MIN(balance) - FROM accounts + MIN(revenue) + FROM rides ); ~~~ ~~~ -+----+------------------+---------+ -| id | name | balance | -+----+------------------+---------+ -| 3 | Arturo Nevin | 250 | -| 10 | Henrik Brankovic | 250 | -| 26 | Odalys Ziemniak | 250 | -| 35 | Vayu Soun | 250 | -+----+------------------+---------+ + id | city | vehicle_id | rider_id ++--------------------------------------+-------------+--------------------------------------+--------------------------------------+ + 1f3b645a-1cac-4800-8000-00000000003d | boston | 22222222-2222-4200-8000-000000000002 | 19999999-9999-4a00-8000-000000000005 + 23d70a3d-70a3-4800-8000-000000000046 | boston | 22222222-2222-4200-8000-000000000002 | 19999999-9999-4a00-8000-000000000005 + 851eb851-eb85-4000-8000-000000000104 | chicago | 88888888-8888-4800-8000-000000000008 | 851eb851-eb85-4000-8000-00000000001a + 85a1cac0-8312-4000-8000-000000000105 | chicago | 88888888-8888-4800-8000-000000000008 | 947ae147-ae14-4800-8000-00000000001d + 722d0e56-0418-4400-8000-0000000000df | los angeles | 77777777-7777-4800-8000-000000000007 | 7ae147ae-147a-4000-8000-000000000018 + ae147ae1-47ae-4800-8000-000000000154 | minneapolis | aaaaaaaa-aaaa-4800-8000-00000000000a | b851eb85-1eb8-4000-8000-000000000024 + 0dd2f1a9-fbe7-4c80-8000-00000000001b | new york | 11111111-1111-4100-8000-000000000001 | 00000000-0000-4000-8000-000000000000 + f4bc6a7e-f9db-4000-8000-0000000001de | rome | eeeeeeee-eeee-4000-8000-00000000000e | f0a3d70a-3d70-4000-8000-00000000002f +(8 rows) ~~~ #### Perform aggregate function on retrieved rows @@ -306,17 +322,14 @@ By filtering the statement, you can perform the calculation only on retrieved ro {% include copy-clipboard.html %} ~~~ sql -> SELECT SUM(balance) -FROM accounts -WHERE state_opened IN ('AZ', 'NY', 'WA'); +> SELECT SUM(revenue) FROM rides WHERE city IN ('new york', 'chicago'); ~~~ ~~~ -+--------------+ -| SUM(balance) | -+--------------+ -| 4950 | -+--------------+ + sum ++---------+ + 4079.00 +(1 row) ~~~ #### Filter columns fed into aggregate functions @@ -325,15 +338,14 @@ You can use `FILTER (WHERE )` in the `target_elem` to filter {% include copy-clipboard.html %} ~~~ sql -> SELECT count(*) AS unfiltered, count(*) FILTER (WHERE balance > 1500) AS filtered FROM accounts; +> SELECT count(*) AS unfiltered, count(*) FILTER (WHERE revenue > 50) AS filtered FROM rides; ~~~ ~~~ + unfiltered | filtered +------------+----------+ -| unfiltered | filtered | -+------------+----------+ -| 84 | 14 | -+------------+----------+ + 500 | 252 +(1 row) ~~~ #### Create aggregate groups @@ -346,20 +358,17 @@ For example: {% include copy-clipboard.html %} ~~~ sql -> SELECT state_opened AS state, SUM(balance) AS state_balance -FROM accounts -WHERE state_opened IN ('AZ', 'NY', 'WA') -GROUP BY state_opened; +> SELECT city, SUM(revenue) AS city_revenue FROM rides +WHERE city IN ('new york', 'chicago', 'seattle') GROUP BY city; ~~~ ~~~ -+-------+---------------+ -| state | state_balance | -+-------+---------------+ -| AZ | 300 | -| NY | 1700 | -| WA | 2950 | -+-------+---------------+ + city | city_revenue ++----------+--------------+ + chicago | 1990.00 + new york | 2089.00 + seattle | 2029.00 +(3 rows) ~~~ #### Filter aggregate groups @@ -370,21 +379,19 @@ For example: {% include copy-clipboard.html %} ~~~ sql -> SELECT state_opened, AVG(balance) as avg -FROM accounts -GROUP BY state_opened -HAVING AVG(balance) BETWEEN 1700 AND 50000; +> SELECT city, AVG(revenue) as avg FROM rides GROUP BY city +HAVING AVG(revenue) BETWEEN 50 AND 60; ~~~ ~~~ -+--------------+---------+ -| state_opened | avg | -+--------------+---------+ -| AR | 3700.00 | -| UT | 1750.00 | -| OH | 2500.00 | -| AL | 1850.00 | -+--------------+---------+ + city | avg ++---------------+-----------------------+ + amsterdam | 52.50 + boston | 52.666666666666666667 + los angeles | 55.951219512195121951 + minneapolis | 55.146341463414634146 + washington dc | 58.756097560975609756 +(5 rows) ~~~ #### Use aggregate functions in having clause @@ -395,19 +402,17 @@ For example: {% include copy-clipboard.html %} ~~~ sql -> SELECT name, state_opened -FROM accounts -WHERE state_opened in ('LA', 'MO') -GROUP BY name, state_opened -HAVING COUNT(name) > 1; +> SELECT vehicle_id, city FROM rides WHERE city IN ('new york', 'chicago', 'seattle') +GROUP BY vehicle_id, city HAVING COUNT(vehicle_id) > 20; ~~~ ~~~ -+----------------+--------------+ -| name | state_opened | -+----------------+--------------+ -| Yehoshua Kleid | MO | -+----------------+--------------+ + vehicle_id | city ++--------------------------------------+----------+ + 88888888-8888-4800-8000-000000000008 | chicago + 11111111-1111-4100-8000-000000000001 | new york + 44444444-4444-4400-8000-000000000004 | seattle +(3 rows) ~~~ ### Select from a specific index diff --git a/v19.2/show-columns.md b/v19.2/show-columns.md index c1f5c752b3c..c2ddd9476da 100644 --- a/v19.2/show-columns.md +++ b/v19.2/show-columns.md @@ -38,56 +38,27 @@ Field | Description ## Examples -{% include copy-clipboard.html %} -~~~ sql -> CREATE TABLE orders ( - id INT PRIMARY KEY DEFAULT unique_rowid(), - date TIMESTAMP NOT NULL, - priority INT DEFAULT 1, - customer_id INT UNIQUE, - status STRING DEFAULT 'open', - CHECK (priority BETWEEN 1 AND 5), - CHECK (status in ('open', 'in progress', 'done', 'cancelled')), - FAMILY (id, date, priority, customer_id, status) -); -~~~ - -{% include copy-clipboard.html %} -~~~ sql -> SHOW COLUMNS FROM orders; -~~~ - -~~~ - column_name | data_type | is_nullable | column_default | generation_expression | indices | is_hidden -+-------------+-----------+-------------+-----------------+-----------------------+--------------------------------------+-----------+ - id | INT | false | unique_rowid() | | {"primary","orders_customer_id_key"} | false - date | TIMESTAMP | false | NULL | | {} | false - priority | INT | true | 1:::INT | | {} | false - customer_id | INT | true | NULL | | {"orders_customer_id_key"} | false - status | STRING | true | 'open':::STRING | | {} | false -(5 rows) -~~~ - -{% include copy-clipboard.html %} -~~~ sql -> CREATE TABLE foo (x INT); -~~~ +{% include {{page.version.version}}/sql/movr-statements.md %} {% include copy-clipboard.html %} ~~~ sql -> SHOW COLUMNS FROM foo; +> SHOW COLUMNS FROM vehicles; ~~~ ~~~ - column_name | data_type | is_nullable | column_default | generation_expression | indices | is_hidden -+-------------+-----------+-------------+----------------+-----------------------+-------------+-----------+ - x | INT | true | NULL | | {} | false - rowid | INT | false | unique_rowid() | | {"primary"} | true -(2 rows) + column_name | data_type | is_nullable | column_default | generation_expression | indices | is_hidden ++------------------+-----------+-------------+----------------+-----------------------+-------------------------------------------------+-----------+ + id | UUID | false | NULL | | {primary,vehicles_auto_index_fk_city_ref_users} | false + city | STRING | false | NULL | | {primary,vehicles_auto_index_fk_city_ref_users} | false + type | STRING | true | NULL | | {} | false + owner_id | UUID | true | NULL | | {vehicles_auto_index_fk_city_ref_users} | false + creation_time | TIMESTAMP | true | NULL | | {} | false + status | STRING | true | NULL | | {} | false + current_location | STRING | true | NULL | | {} | false + ext | JSONB | true | NULL | | {} | false +(8 rows) ~~~ - - ## See also - [`CREATE TABLE`](create-table.html) diff --git a/v19.2/show-index.md b/v19.2/show-index.md index b1b731c6e1c..c04aad1b70a 100644 --- a/v19.2/show-index.md +++ b/v19.2/show-index.md @@ -47,36 +47,26 @@ Field | Description ## Example -{% include copy-clipboard.html %} -~~~ sql -> CREATE TABLE t1 ( - a INT PRIMARY KEY, - b DECIMAL, - c TIMESTAMP, - d STRING - ); -~~~ +{% include {{page.version.version}}/sql/movr-statements.md %} {% include copy-clipboard.html %} ~~~ sql -> CREATE INDEX b_c_idx ON t1 (b, c) STORING (d); +> CREATE INDEX ON users (name); ~~~ {% include copy-clipboard.html %} ~~~ sql -> SHOW INDEX FROM t1; +> SHOW INDEX FROM users; ~~~ ~~~ -+------------+------------+------------+--------------+-------------+-----------+---------+----------+ -| table_name | index_name | non_unique | seq_in_index | column_name | direction | storing | implicit | -+------------+------------+------------+--------------+-------------+-----------+---------+----------+ -| t1 | primary | false | 1 | a | ASC | false | false | -| t1 | b_c_idx | true | 1 | b | ASC | false | false | -| t1 | b_c_idx | true | 2 | c | ASC | false | false | -| t1 | b_c_idx | true | 3 | d | N/A | true | false | -| t1 | b_c_idx | true | 4 | a | ASC | false | true | -+------------+------------+------------+--------------+-------------+-----------+---------+----------+ + table_name | index_name | non_unique | seq_in_index | column_name | direction | storing | implicit ++------------+----------------+------------+--------------+-------------+-----------+---------+----------+ + users | primary | false | 1 | city | ASC | false | false + users | primary | false | 2 | id | ASC | false | false + users | users_name_idx | true | 1 | name | ASC | false | false + users | users_name_idx | true | 2 | city | ASC | false | true + users | users_name_idx | true | 3 | id | ASC | false | true (5 rows) ~~~ diff --git a/v19.2/show-tables.md b/v19.2/show-tables.md index 4392366c969..91ab8b36b00 100644 --- a/v19.2/show-tables.md +++ b/v19.2/show-tables.md @@ -32,7 +32,7 @@ When a `database_name` and `schema_name` are omitted, the tables of the [current ## Examples -These example assumes that the `bank` database has been set as the current database for the session, either via the [`SET`](set-vars.html) statement or in the client's connection string. +{% include {{page.version.version}}/sql/movr-statements.md %} ### Show tables in the current database @@ -42,93 +42,125 @@ These example assumes that the `bank` database has been set as the current datab ~~~ ~~~ -+---------------+ -| table_name | -+---------------+ -| accounts | -| user_accounts | -+---------------+ -(2 rows) + table_name ++----------------------------+ + promo_codes + rides + user_promo_codes + users + vehicle_location_histories + vehicles +(6 rows) ~~~ This uses the [current schema](sql-name-resolution.html#current-schema) `public` set by default in `search_path`. ### Show tables in a different schema +You can show the tables in schemas other than the current schema. You can also show the schema by table: + {% include copy-clipboard.html %} ~~~ sql -> SHOW TABLES FROM information_schema; +> SHOW TABLES FROM movr.information_schema; ~~~ {% include copy-clipboard.html %} ~~~ sql -> SHOW TABLES FROM bank.information_schema; -- also possible +> SHOW TABLES FROM information_schema; ~~~ +Because `movr` is the current database, these statements return the same output: + ~~~ + table_name +-----------------------------------+ -| table_name | -+-----------------------------------+ -| administrable_role_authorizations | -| applicable_roles | -| column_privileges | -| columns | -| constraint_column_usage | -| enabled_roles | -| key_column_usage | -| parameters | -| referential_constraints | -| role_table_grants | -| routines | -| schema_privileges | -| schemata | -| sequences | -| statistics | -| table_constraints | -| table_privileges | -| tables | -| user_privileges | -| views | -+-----------------------------------+ + administrable_role_authorizations + applicable_roles + column_privileges + columns + constraint_column_usage + enabled_roles + key_column_usage + parameters + referential_constraints + role_table_grants + routines + schema_privileges + schemata + sequences + statistics + table_constraints + table_privileges + tables + user_privileges + views (20 rows) ~~~ + ### Show tables in a different database +You can also show tables from a different database. + {% include copy-clipboard.html %} ~~~ sql -> SHOW TABLES FROM startrek.public; +> SHOW TABLES FROM system.public; ~~~ {% include copy-clipboard.html %} ~~~ sql -> SHOW TABLES FROM startrek; -- also possible +> SHOW TABLES FROM system; ~~~ +Because `public` is the current schema, these statements return the same output: + ~~~ -+-------------------+ -| table_name | -+-------------------+ -| episodes | -| quotes | -| quotes_per_season | -+-------------------+ -(3 rows) + table_name ++------------------+ + comments + descriptor + eventlog + jobs + lease + locations + namespace + rangelog + role_members + settings + table_statistics + ui + users + web_sessions + zones +(15 rows) ~~~ ### Show tables with comments -You can use [`COMMENT ON`](comment-on.html) to add comments on a table. To view a table's comments: +You can use [`COMMENT ON`](comment-on.html) to add comments on a table. +{% include copy-clipboard.html %} +~~~ sql +> COMMENT ON TABLE users IS 'This is a sample comment'; +~~~ + +To view a table's comments: + +{% include copy-clipboard.html %} ~~~ sql -> SHOW TABLES FROM customers WITH COMMENT; +> SHOW TABLES FROM movr WITH COMMENT; ~~~ ~~~ - table_name | comment -+------------+--------------------------+ - dogs | This is a sample comment -(1 row) + table_name | comment ++----------------------------+--------------------------+ + users | This is a sample comment + vehicles | + rides | + vehicle_location_histories | + promo_codes | + user_promo_codes | +(6 rows) ~~~ For more information, see [`COMMENT ON`](comment-on.html). diff --git a/v19.2/update.md b/v19.2/update.md index 7894a18d413..37877975878 100644 --- a/v19.2/update.md +++ b/v19.2/update.md @@ -40,141 +40,147 @@ Parameter | Description ## Examples +{% include {{page.version.version}}/sql/movr-statements.md %} + ### Update a single column in a single row {% include copy-clipboard.html %} ~~~ sql -> SELECT * FROM accounts; +> SELECT * FROM users LIMIT 10; ~~~ ~~~ -+----+----------+----------+ -| id | balance | customer | -+----+----------+----------+ -| 1 | 10000.50 | Ilya | -| 2 | 4000.0 | Julian | -| 3 | 8700.0 | Dario | -| 4 | 3400.0 | Nitin | -+----+----------+----------+ -(4 rows) + id | city | name | address | credit_card ++--------------------------------------+-----------+--------------------+--------------------------------+-------------+ + c28f5c28-f5c2-4000-8000-000000000026 | amsterdam | Maria Weber | 14729 Karen Radial | 5844236997 + c7ae147a-e147-4000-8000-000000000027 | amsterdam | Tina Miller | 97521 Mark Extensions | 8880478663 + cccccccc-cccc-4000-8000-000000000028 | amsterdam | Taylor Cunningham | 89214 Jennifer Well | 5130593761 + d1eb851e-b851-4800-8000-000000000029 | amsterdam | Kimberly Alexander | 48474 Alfred Hollow | 4059628542 + 19999999-9999-4a00-8000-000000000005 | boston | Nicole Mcmahon | 11540 Patton Extensions | 0303726947 + 1eb851eb-851e-4800-8000-000000000006 | boston | Brian Campbell | 92025 Yang Village | 9016427332 + 23d70a3d-70a3-4800-8000-000000000007 | boston | Carl Mcguire | 60124 Palmer Mews Apt. 49 | 4566257702 + 28f5c28f-5c28-4600-8000-000000000008 | boston | Jennifer Sanders | 19121 Padilla Brooks Apt. 12 | 1350968125 + 80000000-0000-4000-8000-000000000019 | chicago | Matthew Clay | 49220 Lisa Junctions | 9132291015 + 851eb851-eb85-4000-8000-00000000001a | chicago | Samantha Coffey | 6423 Jessica Underpass Apt. 87 | 9437219051 +(10 rows) ~~~ {% include copy-clipboard.html %} ~~~ sql -> UPDATE accounts SET balance = 5000.0 WHERE id = 2; +> UPDATE users SET address = '201 E Randolph St' WHERE id = '851eb851-eb85-4000-8000-00000000001a'; ~~~ {% include copy-clipboard.html %} ~~~ sql -> SELECT * FROM accounts; +> SELECT * FROM users LIMIT 10; ~~~ ~~~ -+----+----------+----------+ -| id | balance | customer | -+----+----------+----------+ -| 1 | 10000.50 | Ilya | -| 2 | 5000.0 | Julian | -| 3 | 8700.0 | Dario | -| 4 | 3400.0 | Nitin | -+----+----------+----------+ -(4 rows) + id | city | name | address | credit_card ++--------------------------------------+-----------+--------------------+------------------------------+-------------+ + c28f5c28-f5c2-4000-8000-000000000026 | amsterdam | Maria Weber | 14729 Karen Radial | 5844236997 + c7ae147a-e147-4000-8000-000000000027 | amsterdam | Tina Miller | 97521 Mark Extensions | 8880478663 + cccccccc-cccc-4000-8000-000000000028 | amsterdam | Taylor Cunningham | 89214 Jennifer Well | 5130593761 + d1eb851e-b851-4800-8000-000000000029 | amsterdam | Kimberly Alexander | 48474 Alfred Hollow | 4059628542 + 19999999-9999-4a00-8000-000000000005 | boston | Nicole Mcmahon | 11540 Patton Extensions | 0303726947 + 1eb851eb-851e-4800-8000-000000000006 | boston | Brian Campbell | 92025 Yang Village | 9016427332 + 23d70a3d-70a3-4800-8000-000000000007 | boston | Carl Mcguire | 60124 Palmer Mews Apt. 49 | 4566257702 + 28f5c28f-5c28-4600-8000-000000000008 | boston | Jennifer Sanders | 19121 Padilla Brooks Apt. 12 | 1350968125 + 80000000-0000-4000-8000-000000000019 | chicago | Matthew Clay | 49220 Lisa Junctions | 9132291015 + 851eb851-eb85-4000-8000-00000000001a | chicago | Samantha Coffey | 201 E Randolph St | 9437219051 +(10 rows) ~~~ ### Update multiple columns in a single row {% include copy-clipboard.html %} ~~~ sql -> UPDATE accounts SET (balance, customer) = (9000.0, 'Kelly') WHERE id = 2; +> UPDATE rides SET (end_address, revenue) = ('201 E Randolph St', 25.00) WHERE id = '851eb851-eb85-4000-8000-000000000104'; ~~~ {% include copy-clipboard.html %} ~~~ sql -> SELECT * FROM accounts; +> SELECT * FROM rides WHERE rider_id = '851eb851-eb85-4000-8000-00000000001a'; ~~~ ~~~ -+----+----------+----------+ -| id | balance | customer | -+----+----------+----------+ -| 1 | 10000.50 | Ilya | -| 2 | 9000.0 | Kelly | -| 3 | 8700.0 | Dario | -| 4 | 3400.0 | Nitin | -+----+----------+----------+ -(4 rows) + id | city | vehicle_city | rider_id | vehicle_id | start_address | end_address | start_time | end_time | revenue ++--------------------------------------+---------+--------------+--------------------------------------+--------------------------------------+-------------------------------+-----------------------------+---------------------------+---------------------------+---------+ + 849ba5e3-53f7-4000-8000-000000000103 | chicago | chicago | 851eb851-eb85-4000-8000-00000000001a | 88888888-8888-4800-8000-000000000008 | 77630 Steven Road Suite 60 | 74140 Andrew Spur | 2018-12-30 03:04:05+00:00 | 2018-12-31 08:04:05+00:00 | 20.00 + 851eb851-eb85-4000-8000-000000000104 | chicago | chicago | 851eb851-eb85-4000-8000-00000000001a | 88888888-8888-4800-8000-000000000008 | 76707 Timothy Square | 201 E Randolph St | 2018-12-15 03:04:05+00:00 | 2018-12-17 07:04:05+00:00 | 25.00 + 86a7ef9d-b22d-4000-8000-000000000107 | chicago | chicago | 851eb851-eb85-4000-8000-00000000001a | 88888888-8888-4800-8000-000000000008 | 28532 Kevin Villages Suite 90 | 27493 Ortega Radial Apt. 60 | 2018-12-08 03:04:05+00:00 | 2018-12-09 03:04:05+00:00 | 36.00 + 92f1a9fb-e76c-4800-8000-00000000011f | chicago | chicago | 851eb851-eb85-4000-8000-00000000001a | 88888888-8888-4800-8000-000000000008 | 56955 Edward Walks | 53193 Jerry Village | 2019-01-01 03:04:05+00:00 | 2019-01-01 15:04:05+00:00 | 35.00 + 94fdf3b6-45a1-4800-8000-000000000123 | chicago | chicago | 851eb851-eb85-4000-8000-00000000001a | 88888888-8888-4800-8000-000000000008 | 63820 Robinson Fields | 89245 Eric Orchard | 2018-12-14 03:04:05+00:00 | 2018-12-16 10:04:05+00:00 | 80.00 +(5 rows) ~~~ {% include copy-clipboard.html %} ~~~ sql -> UPDATE accounts SET balance = 6300.0, customer = 'Stanley' WHERE id = 3; +> UPDATE rides SET end_address = '10000 W OHare Ave', revenue = 60.00 WHERE id = '94fdf3b6-45a1-4800-8000-000000000123'; ~~~ {% include copy-clipboard.html %} ~~~ sql -> SELECT * FROM accounts; +> SELECT * FROM rides WHERE rider_id = '851eb851-eb85-4000-8000-00000000001a'; ~~~ ~~~ -+----+----------+----------+ -| id | balance | customer | -+----+----------+----------+ -| 1 | 10000.50 | Ilya | -| 2 | 9000.0 | Kelly | -| 3 | 6300.0 | Stanley | -| 4 | 3400.0 | Nitin | -+----+----------+----------+ -(4 rows) + id | city | vehicle_city | rider_id | vehicle_id | start_address | end_address | start_time | end_time | revenue ++--------------------------------------+---------+--------------+--------------------------------------+--------------------------------------+-------------------------------+-----------------------------+---------------------------+---------------------------+---------+ + 849ba5e3-53f7-4000-8000-000000000103 | chicago | chicago | 851eb851-eb85-4000-8000-00000000001a | 88888888-8888-4800-8000-000000000008 | 77630 Steven Road Suite 60 | 74140 Andrew Spur | 2018-12-30 03:04:05+00:00 | 2018-12-31 08:04:05+00:00 | 20.00 + 851eb851-eb85-4000-8000-000000000104 | chicago | chicago | 851eb851-eb85-4000-8000-00000000001a | 88888888-8888-4800-8000-000000000008 | 76707 Timothy Square | 201 E Randolph St | 2018-12-15 03:04:05+00:00 | 2018-12-17 07:04:05+00:00 | 25.00 + 86a7ef9d-b22d-4000-8000-000000000107 | chicago | chicago | 851eb851-eb85-4000-8000-00000000001a | 88888888-8888-4800-8000-000000000008 | 28532 Kevin Villages Suite 90 | 27493 Ortega Radial Apt. 60 | 2018-12-08 03:04:05+00:00 | 2018-12-09 03:04:05+00:00 | 36.00 + 92f1a9fb-e76c-4800-8000-00000000011f | chicago | chicago | 851eb851-eb85-4000-8000-00000000001a | 88888888-8888-4800-8000-000000000008 | 56955 Edward Walks | 53193 Jerry Village | 2019-01-01 03:04:05+00:00 | 2019-01-01 15:04:05+00:00 | 35.00 + 94fdf3b6-45a1-4800-8000-000000000123 | chicago | chicago | 851eb851-eb85-4000-8000-00000000001a | 88888888-8888-4800-8000-000000000008 | 63820 Robinson Fields | 10000 W OHare Ave | 2018-12-14 03:04:05+00:00 | 2018-12-16 10:04:05+00:00 | 60.00 +(5 rows) ~~~ ### Update using `SELECT` statement {% include copy-clipboard.html %} ~~~ sql -> UPDATE accounts SET (balance, customer) = - (SELECT balance, customer FROM accounts WHERE id = 2) - WHERE id = 4; +> UPDATE rides SET (revenue, start_address) = + (SELECT revenue, end_address FROM rides WHERE id = '94fdf3b6-45a1-4800-8000-000000000123') + WHERE id = '851eb851-eb85-4000-8000-000000000104'; ~~~ {% include copy-clipboard.html %} ~~~ sql -> SELECT * FROM accounts; +> SELECT * FROM rides WHERE rider_id = '851eb851-eb85-4000-8000-00000000001a'; ~~~ ~~~ -+----+----------+----------+ -| id | balance | customer | -+----+----------+----------+ -| 1 | 10000.50 | Ilya | -| 2 | 9000.0 | Kelly | -| 3 | 6300.0 | Stanley | -| 4 | 9000.0 | Kelly | -+----+----------+----------+ -(4 rows) + id | city | vehicle_city | rider_id | vehicle_id | start_address | end_address | start_time | end_time | revenue ++--------------------------------------+---------+--------------+--------------------------------------+--------------------------------------+-------------------------------+-----------------------------+---------------------------+---------------------------+---------+ + 849ba5e3-53f7-4000-8000-000000000103 | chicago | chicago | 851eb851-eb85-4000-8000-00000000001a | 88888888-8888-4800-8000-000000000008 | 77630 Steven Road Suite 60 | 74140 Andrew Spur | 2018-12-30 03:04:05+00:00 | 2018-12-31 08:04:05+00:00 | 20.00 + 851eb851-eb85-4000-8000-000000000104 | chicago | chicago | 851eb851-eb85-4000-8000-00000000001a | 88888888-8888-4800-8000-000000000008 | 10000 W OHare Ave | 201 E Randolph St | 2018-12-15 03:04:05+00:00 | 2018-12-17 07:04:05+00:00 | 60.00 + 86a7ef9d-b22d-4000-8000-000000000107 | chicago | chicago | 851eb851-eb85-4000-8000-00000000001a | 88888888-8888-4800-8000-000000000008 | 28532 Kevin Villages Suite 90 | 27493 Ortega Radial Apt. 60 | 2018-12-08 03:04:05+00:00 | 2018-12-09 03:04:05+00:00 | 36.00 + 92f1a9fb-e76c-4800-8000-00000000011f | chicago | chicago | 851eb851-eb85-4000-8000-00000000001a | 88888888-8888-4800-8000-000000000008 | 56955 Edward Walks | 53193 Jerry Village | 2019-01-01 03:04:05+00:00 | 2019-01-01 15:04:05+00:00 | 35.00 + 94fdf3b6-45a1-4800-8000-000000000123 | chicago | chicago | 851eb851-eb85-4000-8000-00000000001a | 88888888-8888-4800-8000-000000000008 | 63820 Robinson Fields | 10000 W OHare Ave | 2018-12-14 03:04:05+00:00 | 2018-12-16 10:04:05+00:00 | 60.00 +(5 rows) ~~~ ### Update with default values {% include copy-clipboard.html %} ~~~ sql -> UPDATE accounts SET balance = DEFAULT where customer = 'Stanley'; +> UPDATE users SET address = DEFAULT WHERE id = '19999999-9999-4a00-8000-000000000005'; ~~~ {% include copy-clipboard.html %} ~~~ sql -> SELECT * FROM accounts; +> SELECT * FROM users LIMIT 5; ~~~ ~~~ -+----+----------+----------+ -| id | balance | customer | -+----+----------+----------+ -| 1 | 10000.50 | Ilya | -| 2 | 9000.0 | Kelly | -| 3 | NULL | Stanley | -| 4 | 9000.0 | Kelly | -+----+----------+----------+ -(4 rows) + id | city | name | address | credit_card ++--------------------------------------+-----------+--------------------+-----------------------+-------------+ + c28f5c28-f5c2-4000-8000-000000000026 | amsterdam | Maria Weber | 14729 Karen Radial | 5844236997 + c7ae147a-e147-4000-8000-000000000027 | amsterdam | Tina Miller | 97521 Mark Extensions | 8880478663 + cccccccc-cccc-4000-8000-000000000028 | amsterdam | Taylor Cunningham | 89214 Jennifer Well | 5130593761 + d1eb851e-b851-4800-8000-000000000029 | amsterdam | Kimberly Alexander | 48474 Alfred Hollow | 4059628542 + 19999999-9999-4a00-8000-000000000005 | boston | Nicole Mcmahon | NULL | 0303726947 +(5 rows) ~~~ ### Update all rows @@ -182,27 +188,45 @@ Parameter | Description {{site.data.alerts.callout_danger}} If you do not use the `WHERE` clause to specify the rows to be updated, the values for all rows will be updated. {{site.data.alerts.end}} +{{site.data.alerts.callout_info}} +If the [`sql_safe_updates`](use-the-built-in-sql-client.html#allow-potentially-unsafe-sql-statements) session variable is set to `true`, the client will prevent the update. `sql_safe_updates` is set to `true` by default. +{{site.data.alerts.end}} + +{% include copy-clipboard.html %} +~~~ sql +> UPDATE rides SET revenue = 7.00; +~~~ + +~~~ +pq: rejected: UPDATE without WHERE clause (sql_safe_updates = true) +~~~ + +You can use a [`SET`](set-vars.html) statement to set session variables. + +{% include copy-clipboard.html %} +~~~ sql +> SET sql_safe_updates = false; +~~~ {% include copy-clipboard.html %} ~~~ sql -> UPDATE accounts SET balance = 5000.0; +> UPDATE rides SET revenue = 7.00; ~~~ {% include copy-clipboard.html %} ~~~ sql -> SELECT * FROM accounts; +> SELECT * FROM rides LIMIT 5; ~~~ ~~~ -+----+---------+----------+ -| id | balance | customer | -+----+---------+----------+ -| 1 | 5000.0 | Ilya | -| 2 | 5000.0 | Kelly | -| 3 | 5000.0 | Stanley | -| 4 | 5000.0 | Kelly | -+----+---------+----------+ -(4 rows) + id | city | vehicle_city | rider_id | vehicle_id | start_address | end_address | start_time | end_time | revenue ++--------------------------------------+-----------+--------------+--------------------------------------+--------------------------------------+--------------------------------+-----------------------------------+---------------------------+---------------------------+---------+ + c0000000-0000-4000-8000-000000000177 | amsterdam | amsterdam | c28f5c28-f5c2-4000-8000-000000000026 | cccccccc-cccc-4000-8000-00000000000c | 65738 Williams Summit | 72424 Thomas Field Suite 82 | 2018-12-31 03:04:05+00:00 | 2019-01-01 03:04:05+00:00 | 7.00 + c083126e-978d-4000-8000-000000000178 | amsterdam | amsterdam | cccccccc-cccc-4000-8000-000000000028 | cccccccc-cccc-4000-8000-00000000000c | 53613 Johnson Terrace | 12667 Monica Hollow | 2018-12-16 03:04:05+00:00 | 2018-12-17 15:04:05+00:00 | 7.00 + c10624dd-2f1a-4000-8000-000000000179 | amsterdam | amsterdam | c7ae147a-e147-4000-8000-000000000027 | cccccccc-cccc-4000-8000-00000000000c | 61921 Brittany Orchard Apt. 85 | 81157 Stephanie Court Suite 96 | 2018-12-30 03:04:05+00:00 | 2019-01-01 07:04:05+00:00 | 7.00 + c189374b-c6a7-4000-8000-00000000017a | amsterdam | amsterdam | cccccccc-cccc-4000-8000-000000000028 | cccccccc-cccc-4000-8000-00000000000c | 75456 Gray View | 69175 Christopher Shoals Suite 47 | 2018-12-23 03:04:05+00:00 | 2018-12-23 03:04:05+00:00 | 7.00 + c20c49ba-5e35-4000-8000-00000000017b | amsterdam | amsterdam | cccccccc-cccc-4000-8000-000000000028 | cccccccc-cccc-4000-8000-00000000000c | 38892 Joseph Summit Suite 86 | 89582 Melissa Streets | 2018-12-27 03:04:05+00:00 | 2018-12-28 18:04:05+00:00 | 7.00 +(5 rows) ~~~ ### Update and return values @@ -226,16 +250,15 @@ In this example, the `RETURNING` clause returns the `id` value of the row update {% include copy-clipboard.html %} ~~~ sql -> UPDATE accounts SET balance = DEFAULT WHERE id = 1 RETURNING id; +> UPDATE vehicles SET status = 'available' WHERE city = 'new york' RETURNING id; ~~~ ~~~ -+----+ -| id | -+----+ -| 1 | -+----+ -(1 row) + id ++--------------------------------------+ + 00000000-0000-4000-8000-000000000000 + 11111111-1111-4100-8000-000000000001 +(2 rows) ~~~ @@ -250,7 +273,7 @@ import psycopg2 # Connect to the "bank" database. conn = psycopg2.connect( - database='bank', + database='movr', user='root', host='localhost', port=26257 @@ -262,15 +285,15 @@ conn.set_session(autocommit=True) # Open a cursor to perform database operations. cur = conn.cursor() -# Update a row in the "accounts" table +# Update a row in the "vehicles" table # and return the "id" value. cur.execute( - 'UPDATE accounts SET balance = DEFAULT WHERE id = 1 RETURNING id' + "UPDATE vehicles SET status = 'available' WHERE city = 'new york' RETURNING id;" ) # Print out the returned value. rows = cur.fetchall() -print('ID:') +print('IDs:') for row in rows: print([str(cell) for cell in row]) @@ -282,8 +305,9 @@ conn.close() The printed value would look like: ~~~ -ID: -['1'] +IDs: +['00000000-0000-4000-8000-000000000000'] +['11111111-1111-4100-8000-000000000001'] ~~~ @@ -299,19 +323,19 @@ require 'pg' # Connect to the "bank" database. conn = PG.connect( user: 'root', - dbname: 'bank', + dbname: 'movr', host: 'localhost', port: 26257 ) -# Update a row in the "accounts" table +# Update a row in the "vehicles" table # and return the "id" value. conn.exec( - 'UPDATE accounts SET balance = DEFAULT WHERE id = 1 RETURNING id' + "UPDATE vehicles SET status = 'available' WHERE city = 'new york' RETURNING id;" ) do |res| # Print out the returned value. -puts "ID:" +puts "IDs:" res.each do |row| puts row end @@ -324,8 +348,9 @@ conn.close() The printed value would look like: ~~~ -ID: -{"id"=>"1"} +IDs: +{"id"=>"00000000-0000-4000-8000-000000000000"} +{"id"=>"11111111-1111-4100-8000-000000000001"} ~~~ @@ -338,50 +363,51 @@ ID: package main import ( - "database/sql" - "fmt" - "log" + "database/sql" + "fmt" + "log" - _ "github.com/lib/pq" + _ "github.com/lib/pq" ) func main() { - //Connect to the "bank" database. - db, err := sql.Open( - "postgres", - "postgresql://root@localhost:26257/bank?sslmode=disable" - ) - if err != nil { - log.Fatal("error connecting to the database: ", err) - } - - // Update a row in the "accounts" table - // and return the "id" value. - rows, err := db.Query( - "UPDATE accounts SET balance = DEFAULT WHERE id = 1 RETURNING id", - ) - if err != nil { - log.Fatal(err) - } - - // Print out the returned value. - defer rows.Close() - fmt.Println("ID:") - for rows.Next() { - var id int - if err := rows.Scan(&id); err != nil { - log.Fatal(err) - } - fmt.Printf("%d\n", id) - } + //Connect to the "bank" database. + db, err := sql.Open( + "postgres", + "postgresql://root@localhost:26257/movr?sslmode=disable", + ) + if err != nil { + log.Fatal("error connecting to the database: ", err) + } + + // Update a row in the "vehicles" table + // and return the "id" value. + rows, err := db.Query( + "UPDATE vehicles SET status = 'available' WHERE city = 'new york' RETURNING id;", + ) + if err != nil { + log.Fatal(err) + } + + // Print out the returned value. + defer rows.Close() + fmt.Println("IDs:") + for rows.Next() { + var id string + if err := rows.Scan(&id); err != nil { + log.Fatal(err) + } + fmt.Printf("%s\n", id) + } } ~~~ The printed value would look like: ~~~ -ID: -1 +IDs: +00000000-0000-4000-8000-000000000000 +11111111-1111-4100-8000-000000000001 ~~~ @@ -391,61 +417,61 @@ ID: {% include copy-clipboard.html %} ~~~ js -var async = require('async'); - -// Require the driver. -var pg = require('pg'); +var async = require('async') +var pg = require('pg') -// Connect to the "bank" database. +// Config to connect to the "movr" database. var config = { - user: 'root', - host: 'localhost', - database: 'bank', - port: 26257 -}; - -pg.connect(config, function (err, client, done) { - // Closes communication with the database and exits. - var finish = function () { - done(); - process.exit(); - }; - - if (err) { - console.error('could not connect to cockroachdb', err); - finish(); + user: 'root', + host: 'localhost', + database: 'movr', + port: 26257 } - async.waterfall([ - function (next) { - // Update a row in the "accounts" table - // and return the "id" value. - client.query( - `UPDATE accounts SET balance = DEFAULT WHERE id = 1 RETURNING id`, - next - ); + +// Create pool +var pool = new pg.Pool(config) + +pool.connect(function (err, client, done) { + + // Close communication with the database and exit. + var finish = function () { + done() + process.exit() } - ], - function (err, results) { + if (err) { - console.error('error updating and selecting from accounts', err); - finish(); + console.error('could not connect to cockroachdb', err); + finish() } - // Print out the returned value. - console.log('ID:'); - results.rows.forEach(function (row) { - console.log(row); - }); - - finish(); - }); -}); + async.waterfall([function (next) { + client.query( + `UPDATE vehicles SET status = 'available' WHERE city = 'new york' RETURNING id;`, + next + ) + } + ], + function (err, results) { + if (err) { + console.error('error updating and selecting from users', err); + finish() + } + // Print out the returned value. + console.log('IDs:') + results.rows.forEach(function (row) { + console.log(row) + }) + + finish() + }) + }) ~~~ The printed value would like: ~~~ -ID: -{ id: '1' } +IDs: +{ id: '00000000-0000-4000-8000-000000000000' } +{ id: '11111111-1111-4100-8000-000000000001' } ~~~ diff --git a/v19.2/window-functions.md b/v19.2/window-functions.md index 2d4c391efd2..20e7d54bc0d 100644 --- a/v19.2/window-functions.md +++ b/v19.2/window-functions.md @@ -13,7 +13,7 @@ All [aggregate functions][aggregate-functions] can also be used as [window funct {{site.data.alerts.end}} {{site.data.alerts.callout_info}} -The examples on this page use the `users`, `rides`, and `vehicles` tables from our open-source fictional peer-to-peer ride-sharing application,[MovR](https://github.com/cockroachdb/movr). +The examples on this page use the `users`, `rides`, and `vehicles` tables from our open-source fictional peer-to-peer vehicle-sharing application, [MovR](movr.html). {{site.data.alerts.end}} ## How window functions work