diff --git a/docs/sphinx/source/reference/sql_commands/DQL/Operators.rst b/docs/sphinx/source/reference/sql_commands/DQL/Operators.rst index 59cd5c7878..d122b9c207 100644 --- a/docs/sphinx/source/reference/sql_commands/DQL/Operators.rst +++ b/docs/sphinx/source/reference/sql_commands/DQL/Operators.rst @@ -8,6 +8,9 @@ Operators Operators/Logical Operators/Comparison Operators/IS + Operators/BETWEEN + Operators/LIKE + Operators/IN .. list-table:: @@ -16,6 +19,12 @@ Operators * - :ref:`Logical Operators ` - `AND`, `OR`, `NOT` * - :ref:`Comparison Operators ` - - `<`, `>`, `<=`, `>=`, `=`, `!=` + - `<`, `>`, `<=`, `>=`, `=`, `!=`, `IS DISTINCT FROM` * - :ref:`IS Operator ` - `IS`, `IS NOT` + * - :ref:`BETWEEN Operator ` + - `BETWEEN`, `NOT BETWEEN` + * - :ref:`LIKE Operator ` + - `LIKE`, `NOT LIKE` + * - :ref:`IN Operator ` + - `IN`, `NOT IN` diff --git a/docs/sphinx/source/reference/sql_commands/DQL/Operators/BETWEEN.diagram b/docs/sphinx/source/reference/sql_commands/DQL/Operators/BETWEEN.diagram new file mode 100644 index 0000000000..44d6c45104 --- /dev/null +++ b/docs/sphinx/source/reference/sql_commands/DQL/Operators/BETWEEN.diagram @@ -0,0 +1,8 @@ +Diagram( + NonTerminal('expression'), + Optional(Terminal('NOT')), + Terminal('BETWEEN'), + NonTerminal('lower_bound'), + Terminal('AND'), + NonTerminal('upper_bound') +) diff --git a/docs/sphinx/source/reference/sql_commands/DQL/Operators/BETWEEN.rst b/docs/sphinx/source/reference/sql_commands/DQL/Operators/BETWEEN.rst new file mode 100644 index 0000000000..1cb6cabf8a --- /dev/null +++ b/docs/sphinx/source/reference/sql_commands/DQL/Operators/BETWEEN.rst @@ -0,0 +1,228 @@ +======= +BETWEEN +======= + +.. _between: + +Tests whether a value falls within a specified range (inclusive). + +Syntax +====== + +.. raw:: html + :file: BETWEEN.diagram.svg + +The BETWEEN operator is used in WHERE clauses: + +.. code-block:: sql + + SELECT column1, column2 + FROM table_name + WHERE column1 BETWEEN lower_value AND upper_value + +Parameters +========== + +``expression [NOT] BETWEEN lower_bound AND upper_bound`` + Tests whether an expression's value is within the inclusive range ``[lower_bound, upper_bound]``. + +``expression`` + The value to test. Can be a column name, calculation, or any valid expression. + +``lower_bound`` + The lower bound of the range (inclusive). + +``upper_bound`` + The upper bound of the range (inclusive). + +``NOT`` (optional) + Negates the result - returns true if the value is **outside** the range. + +Returns +======= + +Returns: +- ``TRUE`` if ``expression >= lower_bound AND expression <= upper_bound`` +- ``FALSE`` otherwise +- ``NULL`` if any operand is NULL + +With ``NOT BETWEEN``: +- ``TRUE`` if ``expression < lower_bound OR expression > upper_bound`` +- ``FALSE`` otherwise +- ``NULL`` if any operand is NULL + +**Important**: If ``lower_bound > upper_bound``, the range is empty and ``BETWEEN`` always returns ``FALSE``. + +Examples +======== + +Setup +----- + +For these examples, assume we have a ``products`` table: + +.. code-block:: sql + + CREATE TABLE products( + id BIGINT, + name STRING, + price BIGINT, + stock INTEGER, + PRIMARY KEY(id)) + + INSERT INTO products VALUES + (1, 'Widget A', 100, 50), + (2, 'Widget B', 150, 30), + (3, 'Gadget X', 200, 20), + (4, 'Tool A', 80, 100), + (5, 'Tool B', 120, 15) + +BETWEEN with Numbers +-------------------- + +Find products with prices between 100 and 150 (inclusive): + +.. code-block:: sql + + SELECT name, price + FROM products + WHERE price BETWEEN 100 AND 150 + +.. list-table:: + :header-rows: 1 + + * - :sql:`name` + - :sql:`price` + * - :json:`"Widget A"` + - :json:`100` + * - :json:`"Widget B"` + - :json:`150` + * - :json:`"Tool B"` + - :json:`120` + +NOT BETWEEN +----------- + +Find products with prices outside the range 100-150: + +.. code-block:: sql + + SELECT name, price + FROM products + WHERE price NOT BETWEEN 100 AND 150 + +.. list-table:: + :header-rows: 1 + + * - :sql:`name` + - :sql:`price` + * - :json:`"Tool A"` + - :json:`80` + * - :json:`"Gadget X"` + - :json:`200` + +BETWEEN with Equal Bounds +-------------------------- + +Test for exact value using BETWEEN: + +.. code-block:: sql + + SELECT name, price + FROM products + WHERE price BETWEEN 100 AND 100 + +.. list-table:: + :header-rows: 1 + + * - :sql:`name` + - :sql:`price` + * - :json:`"Widget A"` + - :json:`100` + +This is equivalent to ``WHERE price = 100``. + +Empty Range +----------- + +If lower bound > upper bound, no rows match: + +.. code-block:: sql + + SELECT name, price + FROM products + WHERE price BETWEEN 150 AND 100 + +Returns empty result set (no rows). + +Combined with OR +---------------- + +Use multiple BETWEEN clauses with OR: + +.. code-block:: sql + + SELECT name, price + FROM products + WHERE price BETWEEN 80 AND 100 OR price BETWEEN 180 AND 220 + +.. list-table:: + :header-rows: 1 + + * - :sql:`name` + - :sql:`price` + * - :json:`"Tool A"` + - :json:`80` + * - :json:`"Widget A"` + - :json:`100` + * - :json:`"Gadget X"` + - :json:`200` + +Important Notes +=============== + +Inclusive Range +--------------- + +``BETWEEN`` uses **inclusive** bounds. Both ``lower_bound`` and ``upper_bound`` are included in the matching range. + +NULL Handling +------------- + +If any operand (expression, lower_bound, or upper_bound) is NULL, the result is NULL: + +.. code-block:: sql + + -- Returns NULL + WHERE NULL BETWEEN 1 AND 10 + + -- Returns NULL + WHERE price BETWEEN NULL AND 100 + + -- Returns NULL + WHERE price BETWEEN 100 AND NULL + +Equivalence +----------- + +``BETWEEN`` is shorthand for a range check: + +.. code-block:: sql + + -- These are equivalent: + WHERE x BETWEEN a AND b + WHERE x >= a AND x <= b + + -- These are equivalent: + WHERE x NOT BETWEEN a AND b + WHERE x < a OR x > b + +Type Compatibility +------------------ + +The expression, lower_bound, and upper_bound must be of compatible types. The comparison follows SQL type coercion rules. + +See Also +======== + +* :ref:`Comparison Operators ` - Other comparison operations diff --git a/docs/sphinx/source/reference/sql_commands/DQL/Operators/Comparison.rst b/docs/sphinx/source/reference/sql_commands/DQL/Operators/Comparison.rst index cd90833873..67af1d31b1 100644 --- a/docs/sphinx/source/reference/sql_commands/DQL/Operators/Comparison.rst +++ b/docs/sphinx/source/reference/sql_commands/DQL/Operators/Comparison.rst @@ -2,11 +2,101 @@ Comparison Operators ==================== - .. _comparison-operators: -TODO: flesh out doc +Standard Comparison Operators +============================== + +We support standard comparison operators: ``>``, ``>=``, ``=``, ``<``, ``<=``, ``!=``, ``<>`` + +If either the left or right operand is NULL, the comparison result is NULL. + +.. code-block:: sql + + SELECT * FROM products WHERE price > 100 + SELECT * FROM products WHERE price <= 50 + SELECT * FROM products WHERE name = 'Widget' + SELECT * FROM products WHERE stock != 0 + +IS DISTINCT FROM +================ + +.. _is_distinct_from: + +Syntax +------ + +.. code-block:: sql + + expression1 IS [NOT] DISTINCT FROM expression2 + +NULL-safe equality comparison that treats NULL values as equal to each other. + +Behavior +-------- + +``IS DISTINCT FROM`` returns: + +- ``FALSE`` if both values are NULL +- ``FALSE`` if both values are equal (and non-NULL) +- ``TRUE`` otherwise + +``IS NOT DISTINCT FROM`` returns: + +- ``TRUE`` if both values are NULL +- ``TRUE`` if both values are equal (and non-NULL) +- ``FALSE`` otherwise + +Comparison with ``=`` +--------------------- + +Unlike the standard ``=`` operator, ``IS DISTINCT FROM`` never returns NULL: + +.. list-table:: + :header-rows: 1 + + * - Expression + - Result + * - ``NULL = NULL`` + - ``NULL`` + * - ``NULL IS DISTINCT FROM NULL`` + - ``FALSE`` + * - ``5 = NULL`` + - ``NULL`` + * - ``5 IS DISTINCT FROM NULL`` + - ``TRUE`` + * - ``5 = 5`` + - ``TRUE`` + * - ``5 IS DISTINCT FROM 5`` + - ``FALSE`` + +Examples +-------- + +.. code-block:: sql + + -- Find rows where value is different from 100 (including NULLs) + SELECT * FROM products + WHERE price IS DISTINCT FROM 100 + + -- Find rows where value equals 100 or is NULL + SELECT * FROM products + WHERE price IS NOT DISTINCT FROM 100 + + -- NULL-safe equality check + SELECT * FROM products + WHERE price IS NOT DISTINCT FROM NULL -- Finds rows where price IS NULL + +Use Cases +--------- + +``IS DISTINCT FROM`` is particularly useful for: + +- Detecting changes between values when NULLs are involved +- Implementing NULL-safe equality checks +- Comparing values where NULL is a meaningful state -We support comparison operators: :sql:`>`, :sql:`>=`, :sql:`=`, :sql:`<`, :sql:`<=`, :sql:`!=` +See Also +======== -If the left or right operand is :sql:`NULL`, the comparison result is :sql:`NULL`. +* :ref:`IS Operator ` - IS NULL, IS TRUE, IS FALSE diff --git a/docs/sphinx/source/reference/sql_commands/DQL/Operators/IN.diagram b/docs/sphinx/source/reference/sql_commands/DQL/Operators/IN.diagram new file mode 100644 index 0000000000..880a68f20c --- /dev/null +++ b/docs/sphinx/source/reference/sql_commands/DQL/Operators/IN.diagram @@ -0,0 +1,11 @@ +Diagram( + NonTerminal('expression'), + Optional(Terminal('NOT')), + Terminal('IN'), + Terminal('('), + OneOrMore( + NonTerminal('value'), + Terminal(',') + ), + Terminal(')') +) diff --git a/docs/sphinx/source/reference/sql_commands/DQL/Operators/IN.rst b/docs/sphinx/source/reference/sql_commands/DQL/Operators/IN.rst new file mode 100644 index 0000000000..b66e304552 --- /dev/null +++ b/docs/sphinx/source/reference/sql_commands/DQL/Operators/IN.rst @@ -0,0 +1,247 @@ +== +IN +== + +.. _in: + +Tests whether a value matches any value in a list. + +Syntax +====== + +.. raw:: html + :file: IN.diagram.svg + +The IN operator is used in WHERE clauses: + +.. code-block:: sql + + SELECT column1, column2 + FROM table_name + WHERE column1 IN (value1, value2, value3) + +Parameters +========== + +``expression [NOT] IN (value1, value2, ...)`` + Tests whether an expression matches any value in the provided list. + +``expression`` + The value to test. Can be a column name, calculation, or any valid expression. + +``value1, value2, ...`` + A comma-separated list of values to compare against. Values must be of compatible types with the expression. + +``NOT`` (optional) + Negates the result - returns true if the expression does **not** match any value in the list. + +Returns +======= + +Returns: + +- ``TRUE`` if the expression equals any value in the list +- ``FALSE`` if the expression does not match any value in the list +- ``NULL`` if: + + - The expression is NULL, OR + - The expression doesn't match any non-NULL value AND the list contains at least one NULL + +Examples +======== + +Setup +----- + +For these examples, assume we have a ``products`` table: + +.. code-block:: sql + + CREATE TABLE products( + id BIGINT, + name STRING, + category STRING, + price BIGINT, + PRIMARY KEY(id)) + + INSERT INTO products VALUES + (1, 'Widget A', 'Electronics', 100), + (2, 'Widget B', 'Electronics', 150), + (3, 'Gadget X', 'Electronics', 200), + (4, 'Tool A', 'Hardware', 80), + (5, 'Tool B', 'Hardware', 120), + (6, 'Book A', 'Media', 25), + (7, 'Book B', 'Media', 30) + +IN with Numbers +--------------- + +Find products with specific IDs: + +.. code-block:: sql + + SELECT name, price + FROM products + WHERE id IN (1, 3, 5) + +.. list-table:: + :header-rows: 1 + + * - :sql:`name` + - :sql:`price` + * - :json:`"Widget A"` + - :json:`100` + * - :json:`"Gadget X"` + - :json:`200` + * - :json:`"Tool B"` + - :json:`120` + +IN with Strings +--------------- + +Find products in specific categories: + +.. code-block:: sql + + SELECT name, category + FROM products + WHERE category IN ('Electronics', 'Media') + +.. list-table:: + :header-rows: 1 + + * - :sql:`name` + - :sql:`category` + * - :json:`"Widget A"` + - :json:`"Electronics"` + * - :json:`"Widget B"` + - :json:`"Electronics"` + * - :json:`"Gadget X"` + - :json:`"Electronics"` + * - :json:`"Book A"` + - :json:`"Media"` + * - :json:`"Book B"` + - :json:`"Media"` + +NOT IN +------ + +Find products not in specific categories: + +.. code-block:: sql + + SELECT name, category + FROM products + WHERE category NOT IN ('Electronics', 'Media') + +.. list-table:: + :header-rows: 1 + + * - :sql:`name` + - :sql:`category` + * - :json:`"Tool A"` + - :json:`"Hardware"` + * - :json:`"Tool B"` + - :json:`"Hardware"` + +Single Value IN +--------------- + +IN with a single value is equivalent to ``=``: + +.. code-block:: sql + + -- These are equivalent: + WHERE category IN ('Hardware') + WHERE category = 'Hardware' + +Empty List +---------- + +IN with an empty list always returns FALSE: + +.. code-block:: sql + + SELECT * FROM products WHERE id IN () + -- Returns no rows + +Important Notes +=============== + +NULL Handling +------------- + +IN has special NULL semantics that can be surprising: + +1. If the expression is NULL, IN returns NULL: + +.. code-block:: sql + + WHERE NULL IN (1, 2, 3) -- Returns NULL + +2. If the list contains NULL and no match is found, IN returns NULL (not FALSE): + +.. code-block:: sql + + WHERE 5 IN (1, 2, NULL) -- Returns NULL (not FALSE) + WHERE 1 IN (1, 2, NULL) -- Returns TRUE + +3. NOT IN with NULL in the list can produce unexpected results: + +.. code-block:: sql + + -- Be careful with NOT IN when NULLs might be present + WHERE 5 NOT IN (1, 2, NULL) -- Returns NULL (not TRUE!) + +To avoid NULL-related issues with NOT IN, consider filtering NULLs or using alternative approaches. + +Equivalence +----------- + +IN is shorthand for multiple OR comparisons: + +.. code-block:: sql + + -- These are equivalent: + WHERE x IN (1, 2, 3) + WHERE x = 1 OR x = 2 OR x = 3 + + -- These are equivalent: + WHERE x NOT IN (1, 2, 3) + WHERE x != 1 AND x != 2 AND x != 3 + +Type Compatibility +------------------ + +All values in the IN list must be of compatible types with the expression. Mixing incompatible types will result in a type error: + +.. code-block:: sql + + -- ERROR: Type mismatch + WHERE id IN (1, 'two', 3) + +Performance Considerations +-------------------------- + +IN is most efficient with small, static value lists. For large value lists or dynamic values, consider: + +- Using a JOIN with a separate table +- Creating an appropriate index +- Using other filtering strategies + +Subqueries +---------- + +IN does **not** currently support subqueries: + +.. code-block:: sql + + -- NOT SUPPORTED: + WHERE category IN (SELECT category FROM popular_categories) + +Use JOINs or other techniques for set-based filtering. + +See Also +======== + +* :ref:`Comparison Operators ` - Other comparison operations diff --git a/docs/sphinx/source/reference/sql_commands/DQL/Operators/LIKE.diagram b/docs/sphinx/source/reference/sql_commands/DQL/Operators/LIKE.diagram new file mode 100644 index 0000000000..2926869dcf --- /dev/null +++ b/docs/sphinx/source/reference/sql_commands/DQL/Operators/LIKE.diagram @@ -0,0 +1,12 @@ +Diagram( + NonTerminal('expression'), + Optional(Terminal('NOT')), + Terminal('LIKE'), + NonTerminal('pattern'), + Optional( + Sequence( + Terminal('ESCAPE'), + NonTerminal('escape_char') + ) + ) +) diff --git a/docs/sphinx/source/reference/sql_commands/DQL/Operators/LIKE.rst b/docs/sphinx/source/reference/sql_commands/DQL/Operators/LIKE.rst new file mode 100644 index 0000000000..95ae9666ef --- /dev/null +++ b/docs/sphinx/source/reference/sql_commands/DQL/Operators/LIKE.rst @@ -0,0 +1,288 @@ +==== +LIKE +==== + +.. _like: + +Tests whether a string matches a pattern using wildcards. + +Syntax +====== + +.. raw:: html + :file: LIKE.diagram.svg + +The LIKE operator is used in WHERE clauses: + +.. code-block:: sql + + SELECT column1, column2 + FROM table_name + WHERE column1 LIKE 'pattern%' + +Parameters +========== + +``expression [NOT] LIKE pattern [ESCAPE escape_char]`` + Tests whether a string expression matches a pattern containing wildcards. + +``expression`` + The string value to test. Must be of type STRING. + +``pattern`` + A string literal containing the pattern to match. Supports two wildcards: + + - ``%`` - Matches zero or more characters + - ``_`` - Matches exactly one character + +``NOT`` (optional) + Negates the result - returns true if the expression does **not** match the pattern. + +``ESCAPE escape_char`` (optional) + Specifies a single-character escape sequence to treat wildcard characters (``%`` or ``_``) as literals in the pattern. + +Returns +======= + +Returns: +- ``TRUE`` if the expression matches the pattern +- ``FALSE`` if the expression does not match the pattern +- ``NULL`` if either the expression or pattern is NULL + +Examples +======== + +Setup +----- + +For these examples, assume we have a ``products`` table: + +.. code-block:: sql + + CREATE TABLE products( + id BIGINT, + name STRING, + category STRING, + PRIMARY KEY(id)) + + INSERT INTO products VALUES + (1, 'apple', 'fruit'), + (2, 'application', 'software'), + (3, 'appliance', 'hardware'), + (4, 'banana', 'fruit'), + (5, 'bench', 'furniture'), + (6, 'canal', 'infrastructure'), + (7, 'cabal', 'organization') + +Prefix Matching with % +---------------------- + +Find all products whose names start with "app": + +.. code-block:: sql + + SELECT name + FROM products + WHERE name LIKE 'app%' + +.. list-table:: + :header-rows: 1 + + * - :sql:`name` + * - :json:`"apple"` + * - :json:`"application"` + * - :json:`"appliance"` + +Suffix Matching with % +---------------------- + +Find all products whose names end with "tion": + +.. code-block:: sql + + SELECT name + FROM products + WHERE name LIKE '%tion' + +.. list-table:: + :header-rows: 1 + + * - :sql:`name` + * - :json:`"application"` + +Substring Matching with % +------------------------- + +Find all products whose names contain "an": + +.. code-block:: sql + + SELECT name + FROM products + WHERE name LIKE '%an%' + +.. list-table:: + :header-rows: 1 + + * - :sql:`name` + * - :json:`"banana"` + * - :json:`"canal"` + * - :json:`"appliance"` + * - :json:`"application"` + +Single Character Matching with _ +--------------------------------- + +Exact pattern - "c", any char, then "nal": + +.. code-block:: sql + + SELECT name + FROM products + WHERE name LIKE 'c_nal' + +.. list-table:: + :header-rows: 1 + + * - :sql:`name` + * - :json:`"canal"` + +Combining % and _ +----------------- + +Match patterns with multiple wildcards: + +.. code-block:: sql + + SELECT name + FROM products + WHERE name LIKE '_a%' + +.. list-table:: + :header-rows: 1 + + * - :sql:`name` + * - :json:`"banana"` + * - :json:`"canal"` + * - :json:`"cabal"` + +This matches any name where the second character is 'a'. + +NOT LIKE +-------- + +Find products that don't match a pattern: + +.. code-block:: sql + + SELECT name + FROM products + WHERE name NOT LIKE 'app%' + +.. list-table:: + :header-rows: 1 + + * - :sql:`name` + * - :json:`"banana"` + * - :json:`"bench"` + * - :json:`"canal"` + * - :json:`"cabal"` + +ESCAPE Clause +------------- + +To search for literal ``%`` or ``_`` characters, use the ESCAPE clause: + +.. code-block:: sql + + CREATE TABLE files( + id BIGINT, + filename STRING, + PRIMARY KEY(id)) + + INSERT INTO files VALUES + (1, 'report_2024.pdf'), + (2, 'data%summary.txt'), + (3, 'test_file.csv') + + -- Find files with literal underscore before a digit + SELECT filename + FROM files + WHERE filename LIKE '%\\_%' ESCAPE '\\' + +.. list-table:: + :header-rows: 1 + + * - :sql:`filename` + * - :json:`"report_2024.pdf"` + * - :json:`"test_file.csv"` + +With the ESCAPE clause, ``\\_`` matches a literal underscore character. + +Important Notes +=============== + +Case Sensitivity +---------------- + +LIKE comparisons are **case-sensitive**. ``'ABC' LIKE 'abc'`` returns ``FALSE``. + +To perform case-insensitive matching, convert both sides to the same case: + +.. code-block:: sql + + WHERE LOWER(name) LIKE LOWER('APP%') + +NULL Handling +------------- + +If either the expression or pattern is NULL, LIKE returns NULL: + +.. code-block:: sql + + WHERE NULL LIKE 'pattern' -- Returns NULL + WHERE name LIKE NULL -- Returns NULL + +Performance Considerations +-------------------------- + +**Leading wildcards** (e.g., ``'%pattern'`` or ``'%pattern%'``) prevent the use of index scans and may result in full table scans. For optimal performance, avoid leading wildcards when possible. + +Patterns like ``'prefix%'`` (no leading wildcard) can utilize indexes for efficient lookups. + +Wildcard Summary +---------------- + +.. list-table:: + :header-rows: 1 + + * - Wildcard + - Meaning + - Example + - Matches + * - ``%`` + - Zero or more characters + - ``'app%'`` + - ``'app'``, ``'apple'``, ``'application'`` + * - ``_`` + - Exactly one character + - ``'c_t'`` + - ``'cat'``, ``'cot'``, ``'cut'`` + * - ``\\%`` (with ESCAPE) + - Literal ``%`` + - ``'50\\%' ESCAPE '\\'`` + - ``'50%'`` + * - ``\\_`` (with ESCAPE) + - Literal ``_`` + - ``'test\\_file' ESCAPE '\\'`` + - ``'test_file'`` + +Supported Types +=============== + +LIKE only works with STRING types. Attempting to use LIKE with other types (INTEGER, BIGINT, BYTES, etc.) will result in a type error. + +See Also +======== + +* :ref:`Comparison Operators ` - Other comparison operations diff --git a/yaml-tests/src/test/java/DocumentationQueriesTests.java b/yaml-tests/src/test/java/DocumentationQueriesTests.java index e820bad3e7..75a111d8db 100644 --- a/yaml-tests/src/test/java/DocumentationQueriesTests.java +++ b/yaml-tests/src/test/java/DocumentationQueriesTests.java @@ -43,4 +43,9 @@ void castDocumentationQueriesTests(YamlTest.Runner runner) throws Exception { void vectorDocumentationQueriesTests(YamlTest.Runner runner) throws Exception { runner.runYamsql(PREFIX + "/vector-documentation-queries.yamsql"); } + + @TestTemplate + void operatorsDocumentationQueriesTests(YamlTest.Runner runner) throws Exception { + runner.runYamsql(PREFIX + "/operators-documentation-queries.yamsql"); + } } diff --git a/yaml-tests/src/test/resources/documentation-queries/operators-documentation-queries.yamsql b/yaml-tests/src/test/resources/documentation-queries/operators-documentation-queries.yamsql new file mode 100644 index 0000000000..5077bc2244 --- /dev/null +++ b/yaml-tests/src/test/resources/documentation-queries/operators-documentation-queries.yamsql @@ -0,0 +1,157 @@ +--- +options: + supported_version: 4.3.5.0 +--- +schema_template: + create table products(id bigint, name string, category string, price bigint, stock integer, primary key(id)) + create index price_idx as select price from products order by price + create index category_idx as select category from products order by category + create index name_idx as select name from products order by name +--- +setup: + steps: + - query: insert into products + values (1, 'Widget A', 'Electronics', 100, 50), + (2, 'Widget B', 'Electronics', 150, 30), + (3, 'Gadget X', 'Electronics', 200, 20), + (4, 'Tool A', 'Hardware', 80, 100), + (5, 'Tool B', 'Hardware', 120, 15), + (6, 'Book A', 'Media', 25, 200), + (7, 'Book B', 'Media', 30, 150) +--- +test_block: + name: operators-documentation-tests + preset: single_repetition_ordered + tests: + # BETWEEN with numbers + - + - query: SELECT name, price + FROM products + WHERE price BETWEEN 100 AND 150 + ORDER BY price + - supported_version: 4.3.5.0 + - result: [{name: "Widget A", price: 100}, + {name: "Tool B", price: 120}, + {name: "Widget B", price: 150}] + + # NOT BETWEEN + - + - query: SELECT name, price + FROM products + WHERE price NOT BETWEEN 100 AND 150 + ORDER BY price + - supported_version: 4.3.5.0 + - result: [{name: "Book A", price: 25}, + {name: "Book B", price: 30}, + {name: "Tool A", price: 80}, + {name: "Gadget X", price: 200}] + + # BETWEEN with equal bounds + - + - query: SELECT name, price + FROM products + WHERE price BETWEEN 100 AND 100 + - supported_version: 4.3.5.0 + - result: [{name: "Widget A", price: 100}] + + # LIKE prefix matching + - + - query: SELECT name + FROM products + WHERE name LIKE 'W%' + ORDER BY name + - supported_version: 4.3.5.0 + - result: [{name: "Widget A"}, + {name: "Widget B"}] + + # LIKE suffix matching + - + - query: SELECT name + FROM products + WHERE name LIKE '%B' + ORDER BY name + - supported_version: 4.3.5.0 + - result: [{name: "Book B"}, + {name: "Tool B"}, + {name: "Widget B"}] + + # LIKE substring matching + - + - query: SELECT name + FROM products + WHERE name LIKE '%oo%' + ORDER BY name + - supported_version: 4.3.5.0 + - result: [{name: "Book A"}, + {name: "Book B"}, + {name: "Tool A"}, + {name: "Tool B"}] + + # NOT LIKE + - + - query: SELECT name + FROM products + WHERE name NOT LIKE 'Widget%' + ORDER BY name + - supported_version: 4.3.5.0 + - result: [{name: "Book A"}, + {name: "Book B"}, + {name: "Gadget X"}, + {name: "Tool A"}, + {name: "Tool B"}] + + # IN with numbers + - + - query: SELECT name, price + FROM products + WHERE id IN (1, 3, 5) + ORDER BY id + - supported_version: 4.3.5.0 + - result: [{name: "Widget A", price: 100}, + {name: "Gadget X", price: 200}, + {name: "Tool B", price: 120}] + + # IN with strings + - + - query: SELECT name, category + FROM products + WHERE category IN ('Electronics', 'Media') + ORDER BY name + - supported_version: 4.3.5.0 + - unorderedResult: [{name: "Book A", category: "Media"}, + {name: "Book B", category: "Media"}, + {name: "Gadget X", category: "Electronics"}, + {name: "Widget A", category: "Electronics"}, + {name: "Widget B", category: "Electronics"}] + + # NOT IN + - + - query: SELECT name, category + FROM products + WHERE category NOT IN ('Electronics', 'Media') + ORDER BY name + - supported_version: 4.3.5.0 + - result: [{name: "Tool A", category: "Hardware"}, + {name: "Tool B", category: "Hardware"}] + + # IS DISTINCT FROM - basic comparison + - + - query: SELECT name, price + FROM products + WHERE price IS DISTINCT FROM 100 + ORDER BY name + - supported_version: 4.3.5.0 + - result: [{name: "Book A", price: 25}, + {name: "Book B", price: 30}, + {name: "Gadget X", price: 200}, + {name: "Tool A", price: 80}, + {name: "Tool B", price: 120}, + {name: "Widget B", price: 150}] + + # IS NOT DISTINCT FROM - equality check + - + - query: SELECT name, price + FROM products + WHERE price IS NOT DISTINCT FROM 100 + - supported_version: 4.3.5.0 + - result: [{name: "Widget A", price: 100}]