From c52470f192cb999ad0b84ebe3055a142c12546d0 Mon Sep 17 00:00:00 2001 From: Manfred Moser Date: Wed, 24 Jan 2024 12:04:24 -0800 Subject: [PATCH 1/3] Simplify char type docs --- docs/src/main/sphinx/language/types.md | 14 ++++++++------ 1 file changed, 8 insertions(+), 6 deletions(-) diff --git a/docs/src/main/sphinx/language/types.md b/docs/src/main/sphinx/language/types.md index 8418866eb435..6f9337ede91c 100644 --- a/docs/src/main/sphinx/language/types.md +++ b/docs/src/main/sphinx/language/types.md @@ -154,12 +154,14 @@ Single quotes in string literals can be escaped by using another single quote: ### `CHAR` -Fixed length character data. A `CHAR` type without length specified has a default length of 1. -A `CHAR(x)` value always has `x` characters. For example, casting `dog` to `CHAR(7)` -adds 4 implicit trailing spaces. Leading and trailing spaces are included in comparisons of -`CHAR` values. As a result, two character values with different lengths (`CHAR(x)` and -`CHAR(y)` where `x != y`) will never be equal. As with `VARCHAR`, a single quote in a `CHAR` -literal can be escaped with another single quote: +Fixed length character data. A `CHAR` type without length specified has a +default length of 1. A `CHAR(x)` value always has a fixed length of `x` +characters. For example, casting `dog` to `CHAR(7)` adds four implicit trailing +spaces. + +As with `VARCHAR`, a single quote in a `CHAR` literal can be escaped with +another single quote: + ```sql SELECT CHAR 'All right, Mr. DeMille, I''m ready for my close-up.' ``` From 48d0223b587ecc019757ca4f60be7047e2c377bf Mon Sep 17 00:00:00 2001 From: Manfred Moser Date: Fri, 1 Mar 2024 16:28:27 -0800 Subject: [PATCH 2/3] Add comparison example queries --- docs/src/main/sphinx/functions/comparison.md | 44 ++++++++++++++++++++ 1 file changed, 44 insertions(+) diff --git a/docs/src/main/sphinx/functions/comparison.md b/docs/src/main/sphinx/functions/comparison.md index b19c0df6d48c..51b6587619c1 100644 --- a/docs/src/main/sphinx/functions/comparison.md +++ b/docs/src/main/sphinx/functions/comparison.md @@ -298,3 +298,47 @@ WHERE regionkey IN ( ) ORDER by nation.name; ``` + +## Examples + +The following example queries showcase aspects of using comparison functions and +operators related to implied ordering of values, implicit casting, and different +types. + +Ordering: + +```sql +SELECT 'M' BETWEEN 'A' AND 'Z'; -- true +SELECT 'A' < 'B'; -- true +SELECT 'A' < 'a'; -- true +SELECT TRUE > FALSE; -- true +SELECT 'M' BETWEEN 'A' AND 'Z'; -- true +SELECT 'm' BETWEEN 'A' AND 'Z'; -- false +``` + +The following queries show a subtle difference between `char` and `varchar` +types. The length parameter for `varchar` is an optional maximum length +parameter and comparison is based on the data only, ignoring the length: + +```sql +SELECT cast('Test' as varchar(20)) = cast('Test' as varchar(25)); --true +SELECT cast('Test' as varchar(20)) = cast('Test ' as varchar(25)); --false +``` + +The length parameter for `char` defines a fixed length character array. +Comparison with different length automatically includes a cast to the same +larger length. The cast is performed as automatic padding with spaces, and +therefore both queries in the following return `true`: + +```sql +SELECT cast('Test' as char(20)) = cast('Test' as char(25)); -- true +SELECT cast('Test' as char(20)) = cast('Test ' as char(25)); -- true +``` + +The following queries show how date types are ordered, and how date is +implicitly cast to timestamp with zero time values: + +```sql +SELECT DATE '2024-08-22' < DATE '2024-08-31'; +SELECT DATE '2024-08-22' < TIMESTAMP '2024-08-22 8:00:00'; +``` From 503a8d549444210f631b8a4f3eb47b910cf861eb Mon Sep 17 00:00:00 2001 From: Manfred Moser Date: Fri, 1 Mar 2024 16:35:58 -0800 Subject: [PATCH 3/3] Improve formatting and style --- docs/src/main/sphinx/functions/comparison.md | 96 ++++++++++---------- 1 file changed, 47 insertions(+), 49 deletions(-) diff --git a/docs/src/main/sphinx/functions/comparison.md b/docs/src/main/sphinx/functions/comparison.md index 51b6587619c1..5bd0561ff3fc 100644 --- a/docs/src/main/sphinx/functions/comparison.md +++ b/docs/src/main/sphinx/functions/comparison.md @@ -28,37 +28,35 @@ (range-operator)= ## Range operator: BETWEEN -The `BETWEEN` operator tests if a value is within a specified range. -It uses the syntax `value BETWEEN min AND max`: +The `BETWEEN` operator tests if a value is within a specified range. It uses the +syntax `value BETWEEN min AND max`: -``` +```sql SELECT 3 BETWEEN 2 AND 6; ``` -The statement shown above is equivalent to the following statement: +The preceding statement is equivalent to the following statement: -``` +```sql SELECT 3 >= 2 AND 3 <= 6; ``` -To test if a value does not fall within the specified range -use `NOT BETWEEN`: +To test if a value does not fall within the specified range use `NOT BETWEEN`: -``` +```sql SELECT 3 NOT BETWEEN 2 AND 6; ``` The statement shown above is equivalent to the following statement: -``` +```sql SELECT 3 < 2 OR 3 > 6; ``` -A `NULL` in a `BETWEEN` or `NOT BETWEEN` statement is evaluated -using the standard `NULL` evaluation rules applied to the equivalent -expression above: +A `NULL` in a `BETWEEN` or `NOT BETWEEN` statement is evaluated using the +standard `NULL` evaluation rules applied to the equivalent expression above: -``` +```sql SELECT NULL BETWEEN 2 AND 4; -- null SELECT 2 BETWEEN NULL AND 6; -- null @@ -68,54 +66,52 @@ SELECT 2 BETWEEN 3 AND NULL; -- false SELECT 8 BETWEEN NULL AND 6; -- false ``` -The `BETWEEN` and `NOT BETWEEN` operators can also be used to -evaluate any orderable type. For example, a `VARCHAR`: +The `BETWEEN` and `NOT BETWEEN` operators can also be used to evaluate any +orderable type. For example, a `VARCHAR`: -``` +```sql SELECT 'Paul' BETWEEN 'John' AND 'Ringo'; -- true ``` -Note that the value, min, and max parameters to `BETWEEN` and `NOT -BETWEEN` must be the same type. For example, Trino will produce an -error if you ask it if John is between 2.3 and 35.2. +Note that the value, min, and max parameters to `BETWEEN` and `NOT BETWEEN` must +be the same type. For example, Trino produces an error if you ask it if `John` +is between `2.3` and `35.2`. (is-null-operator)= ## IS NULL and IS NOT NULL -The `IS NULL` and `IS NOT NULL` operators test whether a value -is null (undefined). Both operators work for all data types. +The `IS NULL` and `IS NOT NULL` operators test whether a value is null +(undefined). Both operators work for all data types. -Using `NULL` with `IS NULL` evaluates to true: +Using `NULL` with `IS NULL` evaluates to `true`: -``` -select NULL IS NULL; -- true +```sql +SELECT NULL IS NULL; -- true ``` But any other constant does not: -``` +```sql SELECT 3.0 IS NULL; -- false ``` (is-distinct-operator)= ## IS DISTINCT FROM and IS NOT DISTINCT FROM -In SQL a `NULL` value signifies an unknown value, so any comparison -involving a `NULL` will produce `NULL`. The `IS DISTINCT FROM` -and `IS NOT DISTINCT FROM` operators treat `NULL` as a known value -and both operators guarantee either a true or false outcome even in -the presence of `NULL` input: +In SQL a `NULL` value signifies an unknown value, so any comparison involving a +`NULL` produces `NULL`. The `IS DISTINCT FROM` and `IS NOT DISTINCT FROM` +operators treat `NULL` as a known value and both operators guarantee either a +true or false outcome even in the presence of `NULL` input: -``` +```sql SELECT NULL IS DISTINCT FROM NULL; -- false SELECT NULL IS NOT DISTINCT FROM NULL; -- true ``` -In the example shown above, a `NULL` value is not considered -distinct from `NULL`. When you are comparing values which may -include `NULL` use these operators to guarantee either a `TRUE` or -`FALSE` result. +In the preceding example a `NULL` value is not considered distinct from `NULL`. +When you are comparing values which may include `NULL` use these operators to +guarantee either a `TRUE` or `FALSE` result. The following truth table demonstrate the handling of `NULL` in `IS DISTINCT FROM` and `IS NOT DISTINCT FROM`: @@ -135,12 +131,13 @@ null. Note that in some other databases, such as PostgreSQL, they only return null if all arguments are null. The following types are supported: -`DOUBLE`, -`BIGINT`, -`VARCHAR`, -`TIMESTAMP`, -`TIMESTAMP WITH TIME ZONE`, -`DATE` + +* `DOUBLE` +* `BIGINT` +* `VARCHAR` +* `TIMESTAMP` +* `TIMESTAMP WITH TIME ZONE` +* `DATE` :::{function} greatest(value1, value2, ..., valueN) -> [same as input] Returns the largest of the provided values. @@ -153,8 +150,8 @@ Returns the smallest of the provided values. (quantified-comparison-predicates)= ## Quantified comparison predicates: ALL, ANY and SOME -The `ALL`, `ANY` and `SOME` quantifiers can be used together with comparison operators in the -following way: +The `ALL`, `ANY` and `SOME` quantifiers can be used together with comparison +operators in the following way: ```text expression operator quantifier ( subquery ) @@ -162,7 +159,7 @@ expression operator quantifier ( subquery ) For example: -``` +```sql SELECT 'hello' = ANY (VALUES 'hello', 'world'); -- true SELECT 21 < ALL (VALUES 19, 20, 21); -- false @@ -170,7 +167,8 @@ SELECT 21 < ALL (VALUES 19, 20, 21); -- false SELECT 42 >= SOME (SELECT 41 UNION ALL SELECT 42 UNION ALL SELECT 43); -- true ``` -Here are the meanings of some quantifier and comparison operator combinations: +Following are the meanings of some quantifier and comparison operator +combinations: :::{list-table} :widths: 40, 60 @@ -213,7 +211,7 @@ matching: Typically it is often used as a condition in `WHERE` statements. An example is a query to find all continents starting with `E`, which returns `Europe`: -``` +```sql SELECT * FROM (VALUES 'America', 'Asia', 'Africa', 'Europe', 'Australia', 'Antarctica') AS t (continent) WHERE continent LIKE 'E%'; ``` @@ -221,7 +219,7 @@ WHERE continent LIKE 'E%'; You can negate the result by adding `NOT`, and get all other continents, all not starting with `E`: -``` +```sql SELECT * FROM (VALUES 'America', 'Asia', 'Africa', 'Europe', 'Australia', 'Antarctica') AS t (continent) WHERE continent NOT LIKE 'E%'; ``` @@ -230,7 +228,7 @@ If you only have one specific character to match, you can use the `_` symbol for each character. The following query uses two underscores and produces only `Asia` as result: -``` +```sql SELECT * FROM (VALUES 'America', 'Asia', 'Africa', 'Europe', 'Australia', 'Antarctica') AS t (continent) WHERE continent LIKE 'A__A'; ``` @@ -239,7 +237,7 @@ The wildcard characters `_` and `%` must be escaped to allow you to match them as literals. This can be achieved by specifying the `ESCAPE` character to use: -``` +```sql SELECT 'South_America' LIKE 'South\_America' ESCAPE '\'; ```