From 4ed2a967b1f574fce92558c8fbc6a5ae5efc5a5b Mon Sep 17 00:00:00 2001 From: soyeric128 Date: Tue, 22 Aug 2023 11:27:47 +0800 Subject: [PATCH 1/2] Create values.md --- .../14-sql-commands/20-query-syntax/values.md | 74 +++++++++++++++++++ 1 file changed, 74 insertions(+) create mode 100644 docs/doc/14-sql-commands/20-query-syntax/values.md diff --git a/docs/doc/14-sql-commands/20-query-syntax/values.md b/docs/doc/14-sql-commands/20-query-syntax/values.md new file mode 100644 index 0000000000000..591bea6f62892 --- /dev/null +++ b/docs/doc/14-sql-commands/20-query-syntax/values.md @@ -0,0 +1,74 @@ +--- +title: VALUES +--- +import FunctionDescription from '@site/src/components/FunctionDescription'; + + + +The VALUES clause is used to define a set of rows explicitly for use in queries. It allows you to provide a list of values that can be used as a temporary table in your SQL statements. + +## Syntax + +```sql +VALUES (value_1_1, value_1_2, ...), (value_2_1, value_2_2, ...), ... +``` +- The VALUES clause is followed by sets of values enclosed in parentheses. +- Each set of values represents a row to be inserted into the temporary table. +- Within each set of values, the individual values are comma-separated and correspond to the columns of the temporary table. +- Databend automatically assigns default column names like *col0*, *col1*, *col2*, and so on when you insert multiple rows without specifying column names. + +## Examples + +These examples demonstrate using the VALUES clause to show city data in various formats: directly, ordered by population, and with structured column aliases: + +```sql +VALUES ('Toronto', 2731571), ('Vancouver', 631486), ('Montreal', 1704694); + +col0 |col1 | +---------+-------+ +Toronto |2731571| +Vancouver| 631486| +Montreal |1704694| + +VALUES ('Toronto', 2731571), ('Vancouver', 631486), ('Montreal', 1704694) ORDER BY col1; + +col0 |col1 | +---------+-------+ +Vancouver| 631486| +Montreal |1704694| +Toronto |2731571| + +SELECT * FROM ( + VALUES ('Toronto', 2731571), + ('Vancouver', 631486), + ('Montreal', 1704694) +) AS CityPopulation(City, Population); + +city |population| +---------+----------+ +Toronto | 2731571| +Vancouver| 631486| +Montreal | 1704694| +``` + +These examples demonstrate how the VALUES clause can be used in a SELECT statement: + +```sql +SELECT col1 +FROM (VALUES ('Toronto', 2731571), ('Vancouver', 631486), ('Montreal', 1704694)); + +col1 | +-------+ +2731571| + 631486| +1704694| + +SELECT col0 AS City, col1 AS Population +FROM (VALUES ('Toronto', 2731571), ('Vancouver', 631486), ('Montreal', 1704694)) +ORDER BY col1 DESC +LIMIT 1; + +city |population| +-------+----------+ +Toronto| 2731571| +``` \ No newline at end of file From f93dd1b41dcf80d57165b1295984718156477dbd Mon Sep 17 00:00:00 2001 From: soyeric128 Date: Tue, 22 Aug 2023 12:18:27 +0800 Subject: [PATCH 2/2] Update values.md --- .../14-sql-commands/20-query-syntax/values.md | 48 ++++++++++++++----- 1 file changed, 35 insertions(+), 13 deletions(-) diff --git a/docs/doc/14-sql-commands/20-query-syntax/values.md b/docs/doc/14-sql-commands/20-query-syntax/values.md index 591bea6f62892..4a2927881d773 100644 --- a/docs/doc/14-sql-commands/20-query-syntax/values.md +++ b/docs/doc/14-sql-commands/20-query-syntax/values.md @@ -19,9 +19,10 @@ VALUES (value_1_1, value_1_2, ...), (value_2_1, value_2_2, ...), ... ## Examples -These examples demonstrate using the VALUES clause to show city data in various formats: directly, ordered by population, and with structured column aliases: +These examples demonstrate using the VALUES clause to show city data in various formats: directly, or ordered by population: ```sql +-- Directly return data VALUES ('Toronto', 2731571), ('Vancouver', 631486), ('Montreal', 1704694); col0 |col1 | @@ -30,6 +31,7 @@ Toronto |2731571| Vancouver| 631486| Montreal |1704694| +-- Order data VALUES ('Toronto', 2731571), ('Vancouver', 631486), ('Montreal', 1704694) ORDER BY col1; col0 |col1 | @@ -37,23 +39,12 @@ col0 |col1 | Vancouver| 631486| Montreal |1704694| Toronto |2731571| - -SELECT * FROM ( - VALUES ('Toronto', 2731571), - ('Vancouver', 631486), - ('Montreal', 1704694) -) AS CityPopulation(City, Population); - -city |population| ----------+----------+ -Toronto | 2731571| -Vancouver| 631486| -Montreal | 1704694| ``` These examples demonstrate how the VALUES clause can be used in a SELECT statement: ```sql +-- Select a single column SELECT col1 FROM (VALUES ('Toronto', 2731571), ('Vancouver', 631486), ('Montreal', 1704694)); @@ -63,6 +54,20 @@ col1 | 631486| 1704694| +-- Select columns with aliases +SELECT * FROM ( + VALUES ('Toronto', 2731571), + ('Vancouver', 631486), + ('Montreal', 1704694) +) AS CityPopulation(City, Population); + +city |population| +---------+----------+ +Toronto | 2731571| +Vancouver| 631486| +Montreal | 1704694| + +-- Select columns with aliases and sorting SELECT col0 AS City, col1 AS Population FROM (VALUES ('Toronto', 2731571), ('Vancouver', 631486), ('Montreal', 1704694)) ORDER BY col1 DESC @@ -71,4 +76,21 @@ LIMIT 1; city |population| -------+----------+ Toronto| 2731571| +``` + +This example demonstrates how to use the VALUES clause to create a temporary table within a Common Table Expression (CTE): + +```sql +WITH citypopulation(city, population) AS ( + VALUES ('Toronto', 2731571), + ('Vancouver', 631486), + ('Montreal', 1704694) +) +SELECT citypopulation.city, citypopulation.population FROM citypopulation; + +city |population| +---------+----------+ +Toronto | 2731571| +Vancouver| 631486| +Montreal | 1704694| ``` \ No newline at end of file