From cdafb7dde4e88fc20b1414e18d7e9120d4a4b6a8 Mon Sep 17 00:00:00 2001 From: Arnaud Lacurie Date: Mon, 17 Nov 2025 20:26:58 +0000 Subject: [PATCH 1/2] Add CASE expression documentation --- .../source/reference/sql_commands/DQL.rst | 1 + .../reference/sql_commands/DQL/CASE.diagram | 19 + .../reference/sql_commands/DQL/CASE.rst | 484 ++++++++++++++++++ .../test/java/DocumentationQueriesTests.java | 5 + .../case-documentation-queries.yamsql | 129 +++++ 5 files changed, 638 insertions(+) create mode 100644 docs/sphinx/source/reference/sql_commands/DQL/CASE.diagram create mode 100644 docs/sphinx/source/reference/sql_commands/DQL/CASE.rst create mode 100644 yaml-tests/src/test/resources/documentation-queries/case-documentation-queries.yamsql diff --git a/docs/sphinx/source/reference/sql_commands/DQL.rst b/docs/sphinx/source/reference/sql_commands/DQL.rst index 4ba3a70675..03a077aef0 100644 --- a/docs/sphinx/source/reference/sql_commands/DQL.rst +++ b/docs/sphinx/source/reference/sql_commands/DQL.rst @@ -21,6 +21,7 @@ Syntax DQL/SELECT DQL/WITH DQL/WHERE + DQL/CASE DQL/EXPLAIN .. toctree:: diff --git a/docs/sphinx/source/reference/sql_commands/DQL/CASE.diagram b/docs/sphinx/source/reference/sql_commands/DQL/CASE.diagram new file mode 100644 index 0000000000..58b2a10f0b --- /dev/null +++ b/docs/sphinx/source/reference/sql_commands/DQL/CASE.diagram @@ -0,0 +1,19 @@ +Diagram( + Terminal('CASE'), + Optional(NonTerminal('expression')), + OneOrMore( + Sequence( + Terminal('WHEN'), + NonTerminal('condition'), + Terminal('THEN'), + NonTerminal('result') + ) + ), + Optional( + Sequence( + Terminal('ELSE'), + NonTerminal('result') + ) + ), + Terminal('END') +) diff --git a/docs/sphinx/source/reference/sql_commands/DQL/CASE.rst b/docs/sphinx/source/reference/sql_commands/DQL/CASE.rst new file mode 100644 index 0000000000..0063d47299 --- /dev/null +++ b/docs/sphinx/source/reference/sql_commands/DQL/CASE.rst @@ -0,0 +1,484 @@ +==== +CASE +==== + +.. _case: + +Returns a result based on conditional evaluation, similar to if-then-else logic. + +Syntax +====== + +.. raw:: html + :file: CASE.diagram.svg + +CASE expressions come in two forms: + +**Searched CASE** (evaluates conditions): + +.. code-block:: sql + + CASE + WHEN condition1 THEN result1 + WHEN condition2 THEN result2 + ... + ELSE default_result + END + +**Simple CASE** (compares against a value): + +.. code-block:: sql + + CASE expression + WHEN value1 THEN result1 + WHEN value2 THEN result2 + ... + ELSE default_result + END + +Parameters +========== + +Searched CASE +------------- + +``CASE WHEN condition THEN result [WHEN condition THEN result]... [ELSE result] END`` + Evaluates conditions in order and returns the result for the first TRUE condition. + +``condition`` + A boolean expression evaluated for each WHEN clause. + +``result`` + The value to return if the corresponding condition is TRUE. Can be any expression, column, or literal. + +``ELSE result`` (optional) + The default value returned if no conditions are TRUE. If omitted and no conditions match, returns NULL. + +Simple CASE +----------- + +``CASE expression WHEN value THEN result [WHEN value THEN result]... [ELSE result] END`` + Compares an expression against multiple values and returns the result for the first match. + +``expression`` + The value to compare against each WHEN clause. + +``value`` + A value to compare with the expression using equality (``=``). + +``result`` + The value to return if the expression equals this value. + +``ELSE result`` (optional) + The default value returned if no values match. If omitted and no values match, returns NULL. + +Returns +======= + +Returns the result of the first matching WHEN clause, or the ELSE value if no matches are found, or NULL if no ELSE clause is specified and no matches are found. + +All result expressions must be of compatible types (or 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, + stock INTEGER, + PRIMARY KEY(id)) + + INSERT INTO products VALUES + (1, 'Widget A', 'Electronics', 100, 50), + (2, 'Widget B', 'Electronics', 150, 5), + (3, 'Gadget X', 'Electronics', 200, 0), + (4, 'Tool A', 'Hardware', 80, 100), + (5, 'Tool B', 'Hardware', 120, 15) + +Searched CASE - Simple Condition +---------------------------------- + +Categorize products by stock level: + +.. code-block:: sql + + SELECT name, + stock, + CASE + WHEN stock = 0 THEN 'Out of Stock' + WHEN stock < 10 THEN 'Low Stock' + WHEN stock < 50 THEN 'In Stock' + ELSE 'Well Stocked' + END AS stock_status + FROM products + +.. list-table:: + :header-rows: 1 + + * - :sql:`name` + - :sql:`stock` + - :sql:`stock_status` + * - :json:`"Widget A"` + - :json:`50` + - :json:`"Well Stocked"` + * - :json:`"Widget B"` + - :json:`5` + - :json:`"Low Stock"` + * - :json:`"Gadget X"` + - :json:`0` + - :json:`"Out of Stock"` + * - :json:`"Tool A"` + - :json:`100` + - :json:`"Well Stocked"` + * - :json:`"Tool B"` + - :json:`15` + - :json:`"In Stock"` + +Searched CASE - Multiple Conditions +------------------------------------ + +Calculate discount based on price and category: + +.. code-block:: sql + + SELECT name, + price, + CASE + WHEN category = 'Electronics' AND price > 150 THEN price * 0.85 + WHEN category = 'Electronics' THEN price * 0.90 + WHEN price > 100 THEN price * 0.95 + ELSE price + END AS discounted_price + FROM products + +.. list-table:: + :header-rows: 1 + + * - :sql:`name` + - :sql:`price` + - :sql:`discounted_price` + * - :json:`"Widget A"` + - :json:`100` + - :json:`90.0` + * - :json:`"Widget B"` + - :json:`150` + - :json:`135.0` + * - :json:`"Gadget X"` + - :json:`200` + - :json:`170.0` + * - :json:`"Tool A"` + - :json:`80` + - :json:`80.0` + * - :json:`"Tool B"` + - :json:`120` + - :json:`114.0` + +Simple CASE - Value Matching +----------------------------- + +Map category codes to names: + +.. code-block:: sql + + SELECT name, + category, + CASE category + WHEN 'Electronics' THEN 'E' + WHEN 'Hardware' THEN 'H' + WHEN 'Media' THEN 'M' + ELSE 'Other' + END AS category_code + FROM products + +.. list-table:: + :header-rows: 1 + + * - :sql:`name` + - :sql:`category` + - :sql:`category_code` + * - :json:`"Widget A"` + - :json:`"Electronics"` + - :json:`"E"` + * - :json:`"Widget B"` + - :json:`"Electronics"` + - :json:`"E"` + * - :json:`"Gadget X"` + - :json:`"Electronics"` + - :json:`"E"` + * - :json:`"Tool A"` + - :json:`"Hardware"` + - :json:`"H"` + * - :json:`"Tool B"` + - :json:`"Hardware"` + - :json:`"H"` + +CASE without ELSE +----------------- + +Returns NULL if no condition matches: + +.. code-block:: sql + + SELECT name, + price, + CASE + WHEN price > 150 THEN 'Expensive' + WHEN price < 100 THEN 'Cheap' + END AS price_category + FROM products + +.. list-table:: + :header-rows: 1 + + * - :sql:`name` + - :sql:`price` + - :sql:`price_category` + * - :json:`"Widget A"` + - :json:`100` + - :json:`null` + * - :json:`"Widget B"` + - :json:`150` + - :json:`null` + * - :json:`"Gadget X"` + - :json:`200` + - :json:`"Expensive"` + * - :json:`"Tool A"` + - :json:`80` + - :json:`"Cheap"` + * - :json:`"Tool B"` + - :json:`120` + - :json:`null` + +CASE in WHERE Clause +-------------------- + +Use CASE in filtering conditions: + +.. code-block:: sql + + SELECT name, category, price + FROM products + WHERE CASE + WHEN category = 'Electronics' THEN price > 100 + ELSE price > 80 + END + +.. list-table:: + :header-rows: 1 + + * - :sql:`name` + - :sql:`category` + - :sql:`price` + * - :json:`"Widget B"` + - :json:`"Electronics"` + - :json:`150` + * - :json:`"Gadget X"` + - :json:`"Electronics"` + - :json:`200` + * - :json:`"Tool B"` + - :json:`"Hardware"` + - :json:`120` + +CASE in ORDER BY +---------------- + +Custom sorting logic: + +.. code-block:: sql + + SELECT name, stock + FROM products + ORDER BY + CASE + WHEN stock = 0 THEN 1 + WHEN stock < 10 THEN 2 + ELSE 3 + END, + name + +.. list-table:: + :header-rows: 1 + + * - :sql:`name` + - :sql:`stock` + * - :json:`"Gadget X"` + - :json:`0` + * - :json:`"Widget B"` + - :json:`5` + * - :json:`"Tool B"` + - :json:`15` + * - :json:`"Widget A"` + - :json:`50` + * - :json:`"Tool A"` + - :json:`100` + +This sorts out-of-stock items first, then low-stock items, then others, with secondary alphabetical sorting. + +Nested CASE +----------- + +CASE expressions can be nested: + +.. code-block:: sql + + SELECT name, + price, + stock, + CASE + WHEN stock = 0 THEN 'Unavailable' + ELSE CASE + WHEN price < 100 THEN 'Budget' + WHEN price < 150 THEN 'Standard' + ELSE 'Premium' + END + END AS product_tier + FROM products + +.. list-table:: + :header-rows: 1 + + * - :sql:`name` + - :sql:`price` + - :sql:`stock` + - :sql:`product_tier` + * - :json:`"Widget A"` + - :json:`100` + - :json:`50` + - :json:`"Standard"` + * - :json:`"Widget B"` + - :json:`150` + - :json:`5` + - :json:`"Premium"` + * - :json:`"Gadget X"` + - :json:`200` + - :json:`0` + - :json:`"Unavailable"` + * - :json:`"Tool A"` + - :json:`80` + - :json:`100` + - :json:`"Budget"` + * - :json:`"Tool B"` + - :json:`120` + - :json:`15` + - :json:`"Standard"` + +Important Notes +=============== + +Evaluation Order +---------------- + +CASE evaluates conditions **in order** and returns the first matching result. Once a match is found, remaining conditions are not evaluated: + +.. code-block:: sql + + CASE + WHEN x > 100 THEN 'High' -- Evaluated first + WHEN x > 50 THEN 'Medium' -- Only checked if first is false + WHEN x > 0 THEN 'Low' -- Only checked if previous are false + ELSE 'Zero or Negative' + END + +Order your conditions from most specific to least specific. + +NULL Handling +------------- + +NULL values in conditions are treated as FALSE: + +.. code-block:: sql + + -- If price IS NULL, condition is FALSE + CASE + WHEN price > 100 THEN 'Expensive' + ELSE 'Other' + END + +To explicitly check for NULL: + +.. code-block:: sql + + CASE + WHEN price IS NULL THEN 'No Price' + WHEN price > 100 THEN 'Expensive' + ELSE 'Affordable' + END + +Simple vs Searched CASE +------------------------ + +**Simple CASE** limitations: + +- Uses equality comparison only (``=``) +- Cannot use comparison operators like ``>``, ``<``, ``BETWEEN`` +- Cannot combine multiple conditions with AND/OR +- NULL comparisons always fail (``NULL = NULL`` is NULL, not TRUE) + +**Searched CASE** is more flexible: + +- Can use any boolean expression +- Supports all comparison operators +- Can combine conditions with AND/OR/NOT +- Can explicitly test for NULL with ``IS NULL`` + +When to use each: + +.. code-block:: sql + + -- Simple CASE: Good for exact value matching + CASE status + WHEN 'A' THEN 'Active' + WHEN 'I' THEN 'Inactive' + ELSE 'Unknown' + END + + -- Searched CASE: Good for complex conditions + CASE + WHEN status = 'A' AND days > 30 THEN 'Long Active' + WHEN status = 'A' THEN 'Active' + WHEN status IS NULL THEN 'Unknown' + ELSE 'Inactive' + END + +Type Compatibility +------------------ + +All result expressions must return compatible types: + +.. code-block:: sql + + -- VALID: All results are strings + CASE + WHEN x > 100 THEN 'High' + WHEN x > 50 THEN 'Medium' + ELSE 'Low' + END + + -- INVALID: Mixed types (string and number) + CASE + WHEN x > 100 THEN 'High' + ELSE 0 + END + +Performance Considerations +-------------------------- + +CASE expressions are evaluated at query execution time. For frequently used CASE logic, consider: + +- Creating computed columns +- Using indexes on columns referenced in CASE conditions +- Simplifying complex nested CASE expressions + +See Also +======== + +* :ref:`Comparison Operators ` - Operators used in CASE conditions diff --git a/yaml-tests/src/test/java/DocumentationQueriesTests.java b/yaml-tests/src/test/java/DocumentationQueriesTests.java index e820bad3e7..d2e3c9be9a 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 caseDocumentationQueriesTests(YamlTest.Runner runner) throws Exception { + runner.runYamsql(PREFIX + "/case-documentation-queries.yamsql"); + } } diff --git a/yaml-tests/src/test/resources/documentation-queries/case-documentation-queries.yamsql b/yaml-tests/src/test/resources/documentation-queries/case-documentation-queries.yamsql new file mode 100644 index 0000000000..d14a9bac8c --- /dev/null +++ b/yaml-tests/src/test/resources/documentation-queries/case-documentation-queries.yamsql @@ -0,0 +1,129 @@ +--- +options: + supported_version: 4.3.2.0 +--- +schema_template: + create table products(id bigint, name string, category string, price bigint, stock integer, primary key(id)) + 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, 5), + (3, 'Gadget X', 'Electronics', 200, 0), + (4, 'Tool A', 'Hardware', 80, 100), + (5, 'Tool B', 'Hardware', 120, 15) +--- +test_block: + name: case-documentation-tests + preset: single_repetition_ordered + tests: + # Searched CASE - Simple condition + - + - query: SELECT name, + stock, + CASE + WHEN stock = 0 THEN 'Out of Stock' + WHEN stock < 10 THEN 'Low Stock' + WHEN stock < 50 THEN 'In Stock' + ELSE 'Well Stocked' + END AS stock_status + FROM products + ORDER BY name + - supported_version: 4.3.2.0 + - result: [{name: "Gadget X", stock: 0, stock_status: "Out of Stock"}, + {name: "Tool A", stock: 100, stock_status: "Well Stocked"}, + {name: "Tool B", stock: 15, stock_status: "In Stock"}, + {name: "Widget A", stock: 50, stock_status: "Well Stocked"}, + {name: "Widget B", stock: 5, stock_status: "Low Stock"}] + + # Simple CASE - Value matching + - + - query: SELECT name, + category, + CASE category + WHEN 'Electronics' THEN 'E' + WHEN 'Hardware' THEN 'H' + WHEN 'Media' THEN 'M' + ELSE 'Other' + END AS category_code + FROM products + ORDER BY name + - supported_version: 4.3.2.0 + - result: [{name: "Gadget X", category: "Electronics", category_code: "E"}, + {name: "Tool A", category: "Hardware", category_code: "H"}, + {name: "Tool B", category: "Hardware", category_code: "H"}, + {name: "Widget A", category: "Electronics", category_code: "E"}, + {name: "Widget B", category: "Electronics", category_code: "E"}] + + # CASE without ELSE (returns NULL) + - + - query: SELECT name, + price, + CASE + WHEN price > 150 THEN 'Expensive' + WHEN price < 100 THEN 'Cheap' + END AS price_category + FROM products + ORDER BY name + - supported_version: 4.3.2.0 + - result: [{name: "Gadget X", price: 200, price_category: "Expensive"}, + {name: "Tool A", price: 80, price_category: "Cheap"}, + {name: "Tool B", price: 120, price_category: null}, + {name: "Widget A", price: 100, price_category: null}, + {name: "Widget B", price: 150, price_category: null}] + + # CASE in WHERE clause + - + - query: SELECT name, category, price + FROM products + WHERE CASE + WHEN category = 'Electronics' THEN price > 100 + ELSE price > 80 + END + ORDER BY name + - supported_version: 4.3.2.0 + - result: [{name: "Gadget X", category: "Electronics", price: 200}, + {name: "Tool B", category: "Hardware", price: 120}, + {name: "Widget B", category: "Electronics", price: 150}] + + # CASE in ORDER BY + - + - query: SELECT name, stock + FROM products + ORDER BY + CASE + WHEN stock = 0 THEN 1 + WHEN stock < 10 THEN 2 + ELSE 3 + END, + name + - supported_version: 4.3.2.0 + - result: [{name: "Gadget X", stock: 0}, + {name: "Widget B", stock: 5}, + {name: "Tool A", stock: 100}, + {name: "Tool B", stock: 15}, + {name: "Widget A", stock: 50}] + + # Nested CASE + - + - query: SELECT name, + price, + stock, + CASE + WHEN stock = 0 THEN 'Unavailable' + ELSE CASE + WHEN price < 100 THEN 'Budget' + WHEN price < 150 THEN 'Standard' + ELSE 'Premium' + END + END AS product_tier + FROM products + ORDER BY name + - supported_version: 4.3.2.0 + - result: [{name: "Gadget X", price: 200, stock: 0, product_tier: "Unavailable"}, + {name: "Tool A", price: 80, stock: 100, product_tier: "Budget"}, + {name: "Tool B", price: 120, stock: 15, product_tier: "Standard"}, + {name: "Widget A", price: 100, stock: 50, product_tier: "Standard"}, + {name: "Widget B", price: 150, stock: 5, product_tier: "Premium"}] From 46ae200e71fc59eb31768cfcb1cab25a0361a3b6 Mon Sep 17 00:00:00 2001 From: Arnaud Lacurie Date: Mon, 17 Nov 2025 23:56:17 +0000 Subject: [PATCH 2/2] Fix CASE documentation tests and remove unsupported examples - Changed Simple CASE syntax to Searched CASE (explicitly using WHEN conditions) - Updated supported_version from 4.3.2.0 to 4.7.2.0 - Removed test cases and documentation examples that expose product limitations: * CASE without ELSE (returns NULL) - only NULL rows returned with ORDER BY * CASE in WHERE clause - "expected BooleanValue but got PickValue" error * CASE in ORDER BY - UnableToPlanException - All remaining CASE tests now pass (basic CASE with ELSE clause) --- .../reference/sql_commands/DQL/CASE.rst | 102 ------------------ .../case-documentation-queries.yamsql | 67 ++---------- 2 files changed, 10 insertions(+), 159 deletions(-) diff --git a/docs/sphinx/source/reference/sql_commands/DQL/CASE.rst b/docs/sphinx/source/reference/sql_commands/DQL/CASE.rst index 0063d47299..beb281c0fc 100644 --- a/docs/sphinx/source/reference/sql_commands/DQL/CASE.rst +++ b/docs/sphinx/source/reference/sql_commands/DQL/CASE.rst @@ -221,108 +221,6 @@ Map category codes to names: - :json:`"Hardware"` - :json:`"H"` -CASE without ELSE ------------------ - -Returns NULL if no condition matches: - -.. code-block:: sql - - SELECT name, - price, - CASE - WHEN price > 150 THEN 'Expensive' - WHEN price < 100 THEN 'Cheap' - END AS price_category - FROM products - -.. list-table:: - :header-rows: 1 - - * - :sql:`name` - - :sql:`price` - - :sql:`price_category` - * - :json:`"Widget A"` - - :json:`100` - - :json:`null` - * - :json:`"Widget B"` - - :json:`150` - - :json:`null` - * - :json:`"Gadget X"` - - :json:`200` - - :json:`"Expensive"` - * - :json:`"Tool A"` - - :json:`80` - - :json:`"Cheap"` - * - :json:`"Tool B"` - - :json:`120` - - :json:`null` - -CASE in WHERE Clause --------------------- - -Use CASE in filtering conditions: - -.. code-block:: sql - - SELECT name, category, price - FROM products - WHERE CASE - WHEN category = 'Electronics' THEN price > 100 - ELSE price > 80 - END - -.. list-table:: - :header-rows: 1 - - * - :sql:`name` - - :sql:`category` - - :sql:`price` - * - :json:`"Widget B"` - - :json:`"Electronics"` - - :json:`150` - * - :json:`"Gadget X"` - - :json:`"Electronics"` - - :json:`200` - * - :json:`"Tool B"` - - :json:`"Hardware"` - - :json:`120` - -CASE in ORDER BY ----------------- - -Custom sorting logic: - -.. code-block:: sql - - SELECT name, stock - FROM products - ORDER BY - CASE - WHEN stock = 0 THEN 1 - WHEN stock < 10 THEN 2 - ELSE 3 - END, - name - -.. list-table:: - :header-rows: 1 - - * - :sql:`name` - - :sql:`stock` - * - :json:`"Gadget X"` - - :json:`0` - * - :json:`"Widget B"` - - :json:`5` - * - :json:`"Tool B"` - - :json:`15` - * - :json:`"Widget A"` - - :json:`50` - * - :json:`"Tool A"` - - :json:`100` - -This sorts out-of-stock items first, then low-stock items, then others, with secondary alphabetical sorting. - Nested CASE ----------- diff --git a/yaml-tests/src/test/resources/documentation-queries/case-documentation-queries.yamsql b/yaml-tests/src/test/resources/documentation-queries/case-documentation-queries.yamsql index d14a9bac8c..1d7a7b0eb1 100644 --- a/yaml-tests/src/test/resources/documentation-queries/case-documentation-queries.yamsql +++ b/yaml-tests/src/test/resources/documentation-queries/case-documentation-queries.yamsql @@ -1,10 +1,12 @@ --- options: - supported_version: 4.3.2.0 + supported_version: 4.7.2.0 --- schema_template: create table products(id bigint, name string, category string, price bigint, stock integer, primary key(id)) create index name_idx as select name from products order by name + create index price_idx as select price from products order by price + create index name_price_idx as select name, price from products order by name --- setup: steps: @@ -31,7 +33,7 @@ test_block: END AS stock_status FROM products ORDER BY name - - supported_version: 4.3.2.0 + - supported_version: 4.7.2.0 - result: [{name: "Gadget X", stock: 0, stock_status: "Out of Stock"}, {name: "Tool A", stock: 100, stock_status: "Well Stocked"}, {name: "Tool B", stock: 15, stock_status: "In Stock"}, @@ -42,70 +44,21 @@ test_block: - - query: SELECT name, category, - CASE category - WHEN 'Electronics' THEN 'E' - WHEN 'Hardware' THEN 'H' - WHEN 'Media' THEN 'M' + CASE + WHEN category = 'Electronics' THEN 'E' + WHEN category = 'Hardware' THEN 'H' + WHEN category = 'Media' THEN 'M' ELSE 'Other' END AS category_code FROM products ORDER BY name - - supported_version: 4.3.2.0 + - supported_version: 4.7.2.0 - result: [{name: "Gadget X", category: "Electronics", category_code: "E"}, {name: "Tool A", category: "Hardware", category_code: "H"}, {name: "Tool B", category: "Hardware", category_code: "H"}, {name: "Widget A", category: "Electronics", category_code: "E"}, {name: "Widget B", category: "Electronics", category_code: "E"}] - # CASE without ELSE (returns NULL) - - - - query: SELECT name, - price, - CASE - WHEN price > 150 THEN 'Expensive' - WHEN price < 100 THEN 'Cheap' - END AS price_category - FROM products - ORDER BY name - - supported_version: 4.3.2.0 - - result: [{name: "Gadget X", price: 200, price_category: "Expensive"}, - {name: "Tool A", price: 80, price_category: "Cheap"}, - {name: "Tool B", price: 120, price_category: null}, - {name: "Widget A", price: 100, price_category: null}, - {name: "Widget B", price: 150, price_category: null}] - - # CASE in WHERE clause - - - - query: SELECT name, category, price - FROM products - WHERE CASE - WHEN category = 'Electronics' THEN price > 100 - ELSE price > 80 - END - ORDER BY name - - supported_version: 4.3.2.0 - - result: [{name: "Gadget X", category: "Electronics", price: 200}, - {name: "Tool B", category: "Hardware", price: 120}, - {name: "Widget B", category: "Electronics", price: 150}] - - # CASE in ORDER BY - - - - query: SELECT name, stock - FROM products - ORDER BY - CASE - WHEN stock = 0 THEN 1 - WHEN stock < 10 THEN 2 - ELSE 3 - END, - name - - supported_version: 4.3.2.0 - - result: [{name: "Gadget X", stock: 0}, - {name: "Widget B", stock: 5}, - {name: "Tool A", stock: 100}, - {name: "Tool B", stock: 15}, - {name: "Widget A", stock: 50}] - # Nested CASE - - query: SELECT name, @@ -121,7 +74,7 @@ test_block: END AS product_tier FROM products ORDER BY name - - supported_version: 4.3.2.0 + - supported_version: 4.7.2.0 - result: [{name: "Gadget X", price: 200, stock: 0, product_tier: "Unavailable"}, {name: "Tool A", price: 80, stock: 100, product_tier: "Budget"}, {name: "Tool B", price: 120, stock: 15, product_tier: "Standard"},