From 5b94839d9d9185faa3a14feb3748e62e16c77c50 Mon Sep 17 00:00:00 2001 From: Edgar Melendrez Date: Thu, 15 Aug 2024 19:15:30 -0700 Subject: [PATCH] [Docs] Batch08: adding examples to string functions (#16871) * batch08 completed * reviewing batch08 * apply corrections suggestions by @FrankChen021 --- docs/querying/sql-functions.md | 268 ++++++++++++++++++++++++++++----- docs/querying/sql-scalar.md | 6 +- 2 files changed, 235 insertions(+), 39 deletions(-) diff --git a/docs/querying/sql-functions.md b/docs/querying/sql-functions.md index 4325537a627..2a814337176 100644 --- a/docs/querying/sql-functions.md +++ b/docs/querying/sql-functions.md @@ -597,11 +597,30 @@ Returns true if the expression is contained in a Base64-serialized Bloom filter. ## BTRIM -`BTRIM(, [])` +Trims characters from both the leading and trailing ends of an expression. Defaults `chars` to a space if none is provided. -**Function type:** [Scalar, string](sql-scalar.md#string-functions) +* **Syntax:** `BTRIM(expr[, chars])` +* **Function type:** Scalar, string -Trims characters from both the leading and trailing ends of an expression. +
Example + +The following example trims the `_` characters from both ends of the string expression. + +```sql +SELECT + '___abc___' AS "original_string", + BTRIM('___abc___', '_') AS "trim_both_ends" +``` + +Returns the following: + +| `original_string` | `trim_both_ends` | +| -- | -- | +| `___abc___` | `abc` | + +
+ +[Learn more](sql-scalar.md#string-functions) ## CASE @@ -1549,11 +1568,30 @@ Returns the leftmost number of characters from an expression, optionally padded ## LTRIM -`LTRIM(, [])` +Trims characters from the leading end of an expression. Defaults `chars` to a space if none is provided. -**Function type:** [Scalar, string](sql-scalar.md#string-functions) +* **Syntax:** `LTRIM(expr[, chars])` +* **Function type:** Scalar, string -Trims characters from the leading end of an expression. +
Example + +The following example trims the `_` characters from the leading end of the string expression. + +```sql +SELECT + '___abc___' AS "original_string", + LTRIM('___abc___', '_') AS "trim_leading_end_of_expression" +``` + +Returns the following: + +| `original_string` | `trim_leading_end_of_expression` | +| -- | -- | +| `___abc___` | `abc___` | + +
+ +[Learn more](sql-scalar.md#string-functions) ## MAX @@ -1859,28 +1897,85 @@ string may refer to capture groups using `$1`, `$2`, etc. ## REPEAT -`REPEAT(, [])` +Repeats the string expression `N` times, where `N` is an integer. -**Function type:** [Scalar, string](sql-scalar.md#string-functions) +* **Syntax:** `REPEAT(expr, N)` +* **Function type:** Scalar, string -Repeats the string expression an integer number of times. +
Example + +The following example returns the string expression `abc` repeated `3` times. + +```sql +SELECT + 'abc' AS "original_string", + REPEAT('abc', 3) AS "with_repetition" +``` + +Returns the following: + +| `original_string` | `with_repetition` | +| -- | -- | +| `abc` | `abcabcabc` | + +
+ +[Learn more](sql-scalar.md#string-functions) ## REPLACE -`REPLACE(expr, pattern, replacement)` +Replaces instances of a substring with a replacement string in the given expression. -**Function type:** [Scalar, string](sql-scalar.md#string-functions) +* **Syntax:** `REPLACE(expr, substring, replacement)` +* **Function type:** Scalar, string -Replaces a pattern with another string in the given expression. +
Example + +The following example replaces instances of the substring `abc` with `XYZ`. + +```sql +SELECT + 'abc 123 abc 123' AS "original_string", + REPLACE('abc 123 abc 123', 'abc', 'XYZ') AS "modified_string" +``` + +Returns the following: + +| `original_string` | `modified_string` | +| -- | -- | +| `abc 123 abc 123` | `XYZ 123 XYZ 123` | + +
+ +[Learn more](sql-scalar.md#string-functions) ## REVERSE -`REVERSE(expr)` - -**Function type:** [Scalar, string](sql-scalar.md#string-functions) - Reverses the given expression. +* **Syntax:** `REVERSE(expr)` +* **Function type:** Scalar, string + +
Example + +The following example reverses the string expression `abc`. + +```sql +SELECT + 'abc' AS "original_string", + REVERSE('abc') AS "reversal" +``` + +Returns the following: + +| `original_string` | `reversal` | +| -- | -- | +| `abc` | `cba` | + +
+ +[Learn more](sql-scalar.md#string-functions) + ## RIGHT Returns the `N` rightmost characters of an expression, where `N` is an integer value. @@ -1954,11 +2049,30 @@ Returns the rightmost number of characters from an expression, optionally padded ## RTRIM -`RTRIM(, [])` +Trims characters from the trailing end of an expression. Defaults `chars` to a space if none is provided. -**Function type:** [Scalar, string](sql-scalar.md#string-functions) +* **Syntax:** `RTRIM(expr[, chars])` +* **Function type:** Scalar, string -Trims characters from the trailing end of an expression. +
Example + +The following example trims the `_` characters from the trailing end of the string expression. + +```sql +SELECT + '___abc___' AS "original_string", + RTRIM('___abc___', '_') AS "trim_end" +``` + +Returns the following: + +| `original_string` | `trim_end` | +| -- | -- | +| `___abc___` | `___abc` | + +
+ +[Learn more](sql-scalar.md#string-functions) ## SAFE_DIVIDE @@ -2074,11 +2188,33 @@ Splits `str1` into an array on the delimiter specified by `str2`, which is a reg ## STRING_FORMAT -`STRING_FORMAT(pattern[, args...])` +Returns a string formatted in the manner of Java's [String.format](https://docs.oracle.com/javase/8/docs/api/java/lang/String.html#format-java.lang.String-java.lang.Object...-). -**Function type:** [Scalar, string](sql-scalar.md#string-functions) +* **Syntax:** `STRING_FORMAT(pattern[, args...])` +* **Function type:** Scalar, string -Returns a string formatted in accordance to Java's String.format method. +
Example + +The following example uses Java String format to pass in `Flight_Number_Reporting_Airline` and `origin_airport` columns, from the `flight-carriers` datasource, as arguments into the string. + +```sql +SELECT + "Flight_Number_Reporting_Airline" AS "flight_number", + "Origin" AS "origin_airport", + STRING_FORMAT('Flight No.%d departing from %s', "Flight_Number_Reporting_Airline", "Origin") AS "departure_announcement" +FROM "flight-carriers" +LIMIT 1 +``` + +Returns the following: + +| `flight_number` | `origin_airport` | `departure_announcement` | +| -- | -- | -- | +| `314` | `SJU` | `Flight No.314 departing from SJU` | + +
+ +[Learn more](sql-scalar.md#string-functions) ## STRING_TO_MV @@ -2099,27 +2235,69 @@ Alias for [`LENGTH`](#length). ## STRPOS -`STRPOS(, )` +Returns the one-based index position of a substring within an expression. If `substring` is not found, returns 0. -**Function type:** [Scalar, string](sql-scalar.md#string-functions) +* **Syntax:** `STRPOS(expr, substring)` +* **Function type:** Scalar, string -Returns the one-based index position of a substring within an expression. +
Example + +The following example returns the one-based index position of `World`. + +```sql +SELECT + 'Hello World!' AS "original_string", + STRPOS('Hello World!', 'World') AS "index" +``` + +Returns the following: + +| `original_string` | `index` | +| -- | -- | +| `Hello World!` | `7` | + +
+ +[Learn more](sql-scalar.md#string-functions) ## SUBSTR -`SUBSTR(, , [])` - -**Function type:** [Scalar, string](sql-scalar.md#string-functions) - Alias for [`SUBSTRING`](#substring). +* **Syntax:** `SUBSTR(expr, index[, length])` +* **Function type:** Scalar, string + +[Learn more](sql-scalar.md#string-functions) + + ## SUBSTRING -`SUBSTRING(, , [])` +Returns a substring of the expression starting at a given one-based index. If `length` is omitted, extracts characters to the end of the string, otherwise returns a substring of `length` characters. -**Function type:** [Scalar, string](sql-scalar.md#string-functions) +* **Syntax:** `SUBSTRING(expr, index[, length])` +* **Function type:** Scalar, string -Returns a substring of the expression starting at a given one-based index. +
Example + +The following example extracts a substring from the string expression `abcdefghi` of length `3` starting at index `4` + +```sql +SELECT + 'abcdefghi' AS "original_string", + SUBSTRING('abcdefghi', 4, 3) AS "substring" +``` + +Returns the following: + +| `original_string` | `substring` | +| -- | -- | +| `abcdefghi` | `def` | + +
+ + + +[Learn more](sql-scalar.md#string-functions) ## SUM @@ -2322,17 +2500,35 @@ Takes the difference between two timestamps, returning the results in the given **Function type:** [JSON](sql-json-functions.md) `TO_JSON_STRING(expr)` - Serializes `expr` into a JSON string. ## TRIM -`TRIM([BOTH|LEADING|TRAILING] [ FROM] expr)` +Trims the leading and/or trailing characters of an expression. Defaults `chars` to a space if none is provided. Defaults to `BOTH` if no directional argument is provided. -**Function type:** [Scalar, string](sql-scalar.md#string-functions) +* **Syntax:** `TRIM([BOTH|LEADING|TRAILING] [chars FROM] expr)` +* **Function type:** Scalar, string -Trims the leading or trailing characters of an expression. +
Example + +The following example trims `_` characters from both ends of the string expression. + +```sql +SELECT + '___abc___' AS "original_string", + TRIM( BOTH '_' FROM '___abc___') AS "trim_expression" +``` + +Returns the following: + +| `original_string` | `trim_expression` | +| -- | -- | +| `___abc___` | `abc` | + +
+ +[Learn more](sql-scalar.md#string-functions) ## TRUNC diff --git a/docs/querying/sql-scalar.md b/docs/querying/sql-scalar.md index fdc4a7424d1..662c9dc9ed6 100644 --- a/docs/querying/sql-scalar.md +++ b/docs/querying/sql-scalar.md @@ -112,12 +112,12 @@ String functions accept strings and return a type appropriate to the function. |`REGEXP_EXTRACT(expr, pattern[, index])`|Apply regular expression `pattern` to `expr` and extract a capture group or `NULL` if there is no match. If `index` is unspecified or zero, returns the first substring that matched the pattern. The pattern may match anywhere inside `expr`. To match the entire string, use the `^` and `$` markers at the start and end of your pattern. When `druid.generic.useDefaultValueForNull = true`, it is not possible to differentiate an empty-string match from a non-match (both return `NULL`).| |`REGEXP_LIKE(expr, pattern)`|Returns whether `expr` matches regular expression `pattern`. The pattern may match anywhere inside `expr`; if you want to match the entire string instead, use the `^` and `$` markers at the start and end of your pattern. Similar to [`LIKE`](sql-operators.md#logical-operators), but uses regexps instead of LIKE patterns. Especially useful in WHERE clauses.| |`REGEXP_REPLACE(expr, pattern, replacement)`|Replaces all occurrences of regular expression `pattern` within `expr` with `replacement`. The replacement string may refer to capture groups using `$1`, `$2`, etc. The pattern may match anywhere inside `expr`; if you want to match the entire string instead, use the `^` and `$` markers at the start and end of your pattern.| -|`REPLACE(expr, pattern, replacement)`|Replaces pattern with replacement in `expr`, and returns the result.| +|`REPLACE(expr, substring, replacement)`|Replaces instances of `substring` in `expr` with `replacement` and returns the result.| |`REPEAT(expr, N)`|Repeats `expr` `N` times.| |`REVERSE(expr)`|Reverses `expr`.| |`STRING_FORMAT(pattern[, args...])`|Returns a string formatted in the manner of Java's [String.format](https://docs.oracle.com/javase/8/docs/api/java/lang/String.html#format-java.lang.String-java.lang.Object...-).| -|`STRPOS(haystack, needle)`|Returns the index of `needle` within `haystack`, with indexes starting from 1. If `needle` is not found, returns 0.| -|`SUBSTRING(expr, index[, length])`|Returns a substring of `expr` starting at `index`, with a max `length`, both measured in UTF-16 code units.| +|`STRPOS(expr, substring)`|Returns the index of `substring` within `expr`, with indexes starting from 1. If `substring` is not found, returns 0.| +|`SUBSTRING(expr, index[, length])`|Returns a substring of `expr` starting at a given one-based index. If `length` is omitted, extracts characters to the end of the string, otherwise returns a substring of `length` UTF-16 characters.| |`SUBSTR(expr, index[, length])`|Alias for `SUBSTRING`.| |`TRIM([BOTH `|` LEADING `|` TRAILING] [chars FROM] expr)`|Returns `expr` with characters removed from the leading, trailing, or both ends of `expr` if they are in `chars`. If `chars` is not provided, it defaults to `''` (a space). If the directional argument is not provided, it defaults to `BOTH`.| |`BTRIM(expr[, chars])`|Alternate form of `TRIM(BOTH chars FROM expr)`.|