diff --git a/docs/en/guides/54-query/02-advanced/stored-procedure.md b/docs/en/guides/54-query/02-advanced/stored-procedure.md index 2065433795..37859ab917 100644 --- a/docs/en/guides/54-query/02-advanced/stored-procedure.md +++ b/docs/en/guides/54-query/02-advanced/stored-procedure.md @@ -7,7 +7,7 @@ A stored procedure is a set of executable commands or logic blocks stored within ## Supported Languages -**Databend currently supports [SQL Scripting](/sql/sql-reference/sql-scripting) only**. Using SQL scripting, users can define procedures with control flow constructs like loops (FOR, WHILE, REPEAT) and conditionals (IF, CASE), enabling complex logic and effective multi-step operations. +**Databend currently supports [SQL Scripting](/sql/stored-procedure-scripting/) only**. Using SQL scripting, users can define procedures with control flow constructs like loops (FOR, WHILE, REPEAT) and conditionals (IF, CASE), enabling complex logic and effective multi-step operations. ## Limitations @@ -62,4 +62,3 @@ CALL PROCEDURE sum_even_numbers(1, 10); │ 30 │ └────────┘ ``` - diff --git a/docs/en/sql-reference/00-sql-reference/42-lambda-expressions.md b/docs/en/sql-reference/00-sql-reference/42-lambda-expressions.md deleted file mode 100644 index f1b44c6910..0000000000 --- a/docs/en/sql-reference/00-sql-reference/42-lambda-expressions.md +++ /dev/null @@ -1,47 +0,0 @@ ---- -title: Lambda Expressions ---- - -Lambda expressions are anonymous functions that allow you to encapsulate logic and pass it as an argument to higher-order functions, such as those for processing arrays, lists, or other complex data types. It typically takes a set of input parameters and a body of code that is executed for each element in a collection or for each comparison in sorting logic. - -## Syntax - -```sql --- Take one parameter - -> - --- Take multiple parameters -(, , ...) -> -``` - -| Parameter | Description | -|-----------------------------------|------------------------------------------------------------------------------------------------| -| `, , ...` | Values that the Lambda will operate on (e.g., elements of an array). | -| `->` | Separates the input parameters from the logic. | -| `` | The logic that applies to the input parameters, often written as a conditional or calculation. | - -## Examples - -This lambda expression takes a single argument n and adds 5 to it: - -```bash -n -> (n + 5) -``` - -This lambda expression takes an integer x and returns `Positive` if x is greater than 0, otherwise it returns `Non-Positive`: - -```bash -x -> (CASE WHEN x > 0 THEN 'Positive' ELSE 'Non-Positive' END) -``` - -This lambda expression checks if num is even. It returns `true` for even numbers and `false` for odd numbers: - -```bash -num -> (num % 2 = 0) -``` - -This lambda expression adds the two parameters x and y: - -```bash -(x, y) -> (x + y) -``` \ No newline at end of file diff --git a/docs/en/sql-reference/00-sql-reference/98-sql-scripting.md b/docs/en/sql-reference/00-sql-reference/98-sql-scripting.md deleted file mode 100644 index 34f47953c2..0000000000 --- a/docs/en/sql-reference/00-sql-reference/98-sql-scripting.md +++ /dev/null @@ -1,442 +0,0 @@ ---- -title: SQL Scripting ---- - -This page outlines the SQL scripting options available in Databend. You can use SQL scripting with either of the following query methods: - -- [Stored Procedure](/sql/sql-commands/ddl/procedure/create-procedure) -- [EXECUTE IMMEDIATE](/sql/sql-commands/administration-cmds/execute-immediate) - -:::note -To use procedures, you need to enable the experimental feature: -```sql -SET global enable_experimental_procedure=1; -``` -::: - -## Variable Declaration - -Variables can be declared using the `LET` keyword, followed by the variable name, an optional type, and the initial value. - -```sql title='Basic Variable Declaration:' -LET x := 100; -LET name := 'Alice'; -``` - -## Result Set Variables - -SQL queries can be executed within the script, and results can be stored in variables or result sets. - -```sql title='Result Set Examples:' --- Store query result in a RESULTSET variable -LET employees RESULTSET := SELECT * FROM employee_table; - --- Iterate over result set -FOR emp IN employees DO - -- Process each row - LET salary := emp.salary * 1.1; -END FOR; -``` - -## Cursors - -Declare a cursor from SQL query -```sql - LET c1 CURSOR FOR SELECT price FROM invoices; -``` - -Declare a cursor from result set -```sql - LET r1 RESULTSET := SELECT price FROM invoices; - LET c1 CURSOR for r1; -``` - -Open cursor and fetch into variable -```sql -LET c1 CURSOR FOR SELECT number from numbers(10); -OPEN c1; -LET price := 0; -FETCH c1 INTO price; -CLOSE c1; -``` - -Iterate over cursor -```sql -LET c1 CURSOR FOR SELECT number from numbers(10); - -for price in c1 do - -- Process each number - select :price; -END FOR; -``` - -## Control Flow Constructs - -### FOR Loop - -Iterates over a range, result set, or cursor. - -```sql title='FOR Loop Examples:' --- Range-based FOR loop -FOR i IN 1 TO 10 DO - -- Process each number - INSERT INTO temp_table VALUES (:i, :i * 2); -END FOR; - --- Result set iteration -LET data RESULTSET := SELECT number FROM numbers(5); -FOR r IN data DO - -- Access r.number - LET squared := r.number * r.number; -END FOR; -``` - -### WHILE Loop - -Executes a block of code as long as a specified condition is true. - -```sql title='WHILE Loop Example:' -CREATE PROCEDURE fibonacci_sum(n INT) -RETURNS INT -LANGUAGE SQL -AS $$ -BEGIN - LET a := 0; - LET b := 1; - LET sum := 0; - LET i := 0; - - WHILE i < n DO - sum := sum + a; - LET temp := a + b; - a := b; - b := temp; - i := i + 1; - END WHILE; - - RETURN sum; -END; -$$; -``` - -### REPEAT Loop - -Executes a block of code until a condition is met. - -```sql title='REPEAT Loop Example:' -LET counter := 0; -LET sum := 0; - -REPEAT - counter := counter + 1; - sum := sum + counter; -UNTIL counter >= 5 END REPEAT; -``` - -### LOOP with BREAK - -Executes a block of code indefinitely until a `BREAK` statement is encountered. - -```sql title='LOOP Example:' -LET i := 0; -LOOP - i := i + 1; - IF i > 10 THEN - BREAK; - END IF; - -- Process logic here -END LOOP; -``` - -### IF Statement - -Executes a block of code based on a condition. - -```sql title='IF Statement Examples:' --- Simple IF-ELSE -IF x > 100 THEN - LET result := 'High'; -ELSEIF x > 50 THEN - LET result := 'Medium'; -ELSE - LET result := 'Low'; -END IF; - -### CASE Statement - -Allows conditional execution of code blocks based on different conditions. - -```sql title='CASE Statement Example:' -CREATE PROCEDURE process_grade(score INT) -RETURNS STRING -LANGUAGE SQL -AS $$ -BEGIN - LET grade:= ''; - - CASE - WHEN score >= 90 THEN grade := 'A'; - WHEN score >= 80 THEN grade := 'B'; - WHEN score >= 70 THEN grade := 'C'; - WHEN score >= 60 THEN grade := 'D'; - ELSE grade := 'F'; - END CASE; - - RETURN grade; -END; -$$; -``` - - -## Procedure Examples - -### Basic Mathematical Computation - -```sql title='Convert Units Procedure:' -CREATE PROCEDURE convert_kg_to_lb(kg INT) -RETURNS INT -LANGUAGE SQL -COMMENT = 'Converts kilograms to pounds' -AS $$ -BEGIN - RETURN kg * 2.20462; -END; -$$; - --- Usage -CALL PROCEDURE convert_kg_to_lb(70::Int); -``` - - -### Batch Processing with Loops - -```sql title='Batch Data Processing:' -CREATE OR REPLACE PROCEDURE process_daily_sales() -RETURNS STRING NOT NULL -LANGUAGE SQL -AS $$ -BEGIN - LET sales_data RESULTSET := - SELECT product_id, SUM(quantity) as total_quantity, SUM(amount) as total_amount - FROM daily_sales - WHERE sale_date = today() - GROUP BY product_id; - - LET processed_count := 0; - - FOR sale IN sales_data DO - -- Update product statistics - LET total_quantity := sale.total_quantity; - LET total_amount := sale.total_amount; - LET product_id := sale.product_id; - UPDATE product_stats - SET - total_sold = total_sold + :total_quantity, - total_revenue = total_revenue + :total_amount, - last_updated = NOW() - WHERE product_id = :product_id; - - processed_count := processed_count + 1; - END FOR; - - -- Clean up daily sales - DELETE FROM daily_sales WHERE sale_date = today(); - - RETURN 'Processed ' || processed_count || ' products'; -END; -$$; -``` - -## EXECUTE IMMEDIATE - -`EXECUTE IMMEDIATE` allows you to run SQL scripting blocks without creating stored procedures. - -```sql title='Basic EXECUTE IMMEDIATE:' -EXECUTE IMMEDIATE $$ -BEGIN - LET sum := 0; - FOR x IN SELECT number FROM numbers(10) DO - sum := sum + x.number; - END FOR; - RETURN sum; -END; -$$; -``` - -If the script is single statement, the result is same as the statement. -```sql -EXECUTE IMMEDIATE 'select 1'; -``` - -## Return Statements - -### RETURN - -Returns from the script or procedure with an optional value, by default it returns if no value is specified. - -```sql title='RETURN Examples:' --- Return a simple value -RETURN 42; - --- Return a calculated value -RETURN x * 2 + 10; - --- Return a string -RETURN 'Processing completed successfully'; - - -### RETURN TABLE - -Returns from the script with a table result. This is particularly useful in EXECUTE IMMEDIATE blocks. - -```sql title='RETURN TABLE Examples:' --- Basic table return -EXECUTE IMMEDIATE $$ -BEGIN - CREATE OR REPLACE TABLE t1 (a INT, b FLOAT, c STRING); - INSERT INTO t1 VALUES (1, 2.0, '3'), (4, 5.0, '6'); - RETURN TABLE(SELECT * FROM t1); -END; -$$; - --- Dynamic table creation and return -EXECUTE IMMEDIATE $$ -BEGIN - -- Create summary table - CREATE OR REPLACE TABLE monthly_summary ( - month STRING, - total_sales DECIMAL(15,2), - order_count INT - ); - - -- Populate with aggregated data - INSERT INTO monthly_summary - SELECT - DATE_FORMAT(order_date, '%Y-%m') as month, - SUM(total_amount) as total_sales, - COUNT(*) as order_count - FROM orders - WHERE order_date >= '2024-01-01' - GROUP BY DATE_FORMAT(order_date, '%Y-%m') - ORDER BY month; - - RETURN TABLE(SELECT * FROM monthly_summary); -END; -$$; -``` - -The result will be displayed as a formatted table: - -``` -╭────────────────────────────────────────────────────────╮ -│ a │ b │ c │ -│ Nullable(Int32) │ Nullable(Float32) │ Nullable(String) │ -├─────────────────┼───────────────────┼──────────────────┤ -│ 1 │ 2 │ 3 │ -│ 4 │ 5 │ 6 │ -╰────────────────────────────────────────────────────────╯ -``` - -## Comments - -SQL scripting supports both single-line and multi-line comments: - -```sql title='Comment Examples:' --- Single-line comment -LET x := 10; -- This is also a single-line comment - -/* -Multi-line comment -can span multiple lines -*/ -LET y := /* inline comment */ 20; - -/* -Nested comments are supported: -/* This is a nested comment */ -*/ -``` - -## Advanced Features - -### Variable Scope - -Variables have block scope and can be shadowed in nested blocks: - -```sql title='Variable Scope Example:' -CREATE PROCEDURE scope_demo() -RETURNS STRING -LANGUAGE SQL -AS $$ -BEGIN - LET x := 'outer'; - - IF TRUE THEN - LET x := 'inner'; -- Shadows outer x - -- x is 'inner' here - END IF; - - -- x is 'outer' again here - RETURN x; -END; -$$; -``` - -### Transaction Behavior - -Procedures run within transactions and support automatic rollback on errors: - -```sql title='Transaction Example:' -CREATE PROCEDURE transfer_with_log(from_id INT, to_id INT, amount DECIMAL(10,2)) -RETURNS STRING -LANGUAGE SQL -AS $$ -BEGIN - -- All operations are within the same transaction - UPDATE accounts SET balance = balance - amount WHERE id = from_id; - UPDATE accounts SET balance = balance + amount WHERE id = to_id; - - -- Log the transaction - INSERT INTO transaction_log (from_account, to_account, amount, timestamp) - VALUES (from_id, to_id, amount, NOW()); - - -- If any operation fails, everything is automatically rolled back - RETURN 'Transfer completed'; -END; -$$; -``` - -## Best Practices - -1. **Use meaningful variable names**: `LET total_amount := 0;` instead of `LET x := 0;` - -2. **Add comments for complex logic**: - ```sql - -- Calculate compound interest with monthly compounding - FOR month IN 1 TO months DO - balance := balance * (1 + annual_rate / 12); - END FOR; - ``` - -3. **Handle edge cases**: - ```sql - IF input_value IS NULL THEN - RETURN 'Invalid input: NULL value not allowed'; - END IF; - ``` - -4. **Use appropriate return types**: - ```sql - CREATE PROCEDURE calculate_discount(amount DECIMAL(10,2)) - RETURNS DECIMAL(10,2) NOT NULL -- Specify NOT NULL when appropriate - ``` - -5. **Organize complex procedures with clear sections**: - ```sql - BEGIN - -- Input validation - -- Business logic - -- Data persistence - -- Return result - END; - ``` \ No newline at end of file diff --git a/docs/en/sql-reference/00-sql-reference/index.md b/docs/en/sql-reference/00-sql-reference/index.md index 7eeaf44823..5362db9849 100644 --- a/docs/en/sql-reference/00-sql-reference/index.md +++ b/docs/en/sql-reference/00-sql-reference/index.md @@ -9,4 +9,6 @@ Welcome to SQL Reference – your swift-access guide for Databend essentials! - **SQL Commands:** Detailed information, syntax, and practical examples for executing commands, empowering confident data management in Databend. -- **SQL Functions:** A concise guide to Databend's functions, providing insights into their diverse functionalities for effective data management and analysis. \ No newline at end of file +- **SQL Functions:** A concise guide to Databend's functions, providing insights into their diverse functionalities for effective data management and analysis. + +- **Stored Procedure & Scripting:** Covers the SQL scripting language, including variables, control flow, result handling, and dynamic execution within stored procedures. diff --git a/docs/en/sql-reference/10-sql-commands/00-ddl/18-procedure/index.md b/docs/en/sql-reference/10-sql-commands/00-ddl/18-procedure/index.md index 1083c9d9e7..f6b6bea469 100644 --- a/docs/en/sql-reference/10-sql-commands/00-ddl/18-procedure/index.md +++ b/docs/en/sql-reference/10-sql-commands/00-ddl/18-procedure/index.md @@ -21,4 +21,8 @@ This page provides a comprehensive overview of Stored Procedure operations in Da :::note Stored procedures in Databend allow you to encapsulate a series of SQL statements into a reusable unit that can be executed as a single command, improving code organization and maintainability. -::: \ No newline at end of file +::: + +## Further Reading + +Explore [Stored Procedure & SQL Scripting](/sql/stored-procedure-scripting/) for a complete language reference, including variable handling, control flow, cursors, and dynamic SQL usage within procedures. diff --git a/docs/en/sql-reference/10-sql-commands/50-administration-cmds/execute-immediate.md b/docs/en/sql-reference/10-sql-commands/50-administration-cmds/execute-immediate.md index 05173ca90b..ed584b00f4 100644 --- a/docs/en/sql-reference/10-sql-commands/50-administration-cmds/execute-immediate.md +++ b/docs/en/sql-reference/10-sql-commands/50-administration-cmds/execute-immediate.md @@ -5,7 +5,7 @@ import FunctionDescription from '@site/src/components/FunctionDescription'; -Executes a SQL script. For how to write SQL scripts for Databend, see [SQL Scripting](/sql/sql-reference/sql-scripting). +Executes a SQL script. For how to write SQL scripts for Databend, see [Stored Procedure & SQL Scripting](/sql/stored-procedure-scripting/). ## Syntax @@ -65,4 +65,4 @@ $$; │ │ 2 │ │ │ └───────┘ │ └───────────┘ -``` \ No newline at end of file +``` diff --git a/docs/en/sql-reference/20-sql-functions/10-semi-structured-functions/1-array/array-filter.md b/docs/en/sql-reference/20-sql-functions/10-semi-structured-functions/1-array/array-filter.md index 6a99be3b6b..30460c7780 100644 --- a/docs/en/sql-reference/20-sql-functions/10-semi-structured-functions/1-array/array-filter.md +++ b/docs/en/sql-reference/20-sql-functions/10-semi-structured-functions/1-array/array-filter.md @@ -6,7 +6,7 @@ import FunctionDescription from '@site/src/components/FunctionDescription'; -Filters elements from a JSON array based on a specified Lambda expression, returning only the elements that satisfy the condition. For more information about Lambda expression, see [Lambda Expressions](../../../00-sql-reference/42-lambda-expressions.md). +Filters elements from a JSON array based on a specified Lambda expression, returning only the elements that satisfy the condition. For more information about Lambda expression, see [Lambda Expressions](/sql/stored-procedure-scripting/#lambda-expressions). ## Syntax @@ -30,4 +30,4 @@ SELECT ARRAY_FILTER( -[ RECORD 1 ]----------------------------------- array_filter(['apple', 'banana', 'avocado', 'grape'], d -> d::STRING LIKE 'a%'): ["apple","avocado"] -``` \ No newline at end of file +``` diff --git a/docs/en/sql-reference/20-sql-functions/10-semi-structured-functions/1-array/array-reduce.md b/docs/en/sql-reference/20-sql-functions/10-semi-structured-functions/1-array/array-reduce.md index 887cd0ebf8..450b391aac 100644 --- a/docs/en/sql-reference/20-sql-functions/10-semi-structured-functions/1-array/array-reduce.md +++ b/docs/en/sql-reference/20-sql-functions/10-semi-structured-functions/1-array/array-reduce.md @@ -6,7 +6,7 @@ import FunctionDescription from '@site/src/components/FunctionDescription'; -Reduces a JSON array to a single value by applying a specified Lambda expression. For more information about Lambda expression, see [Lambda Expressions](../../../00-sql-reference/42-lambda-expressions.md). +Reduces a JSON array to a single value by applying a specified Lambda expression. For more information about Lambda expression, see [Lambda Expressions](/sql/stored-procedure-scripting/#lambda-expressions). ## Syntax @@ -26,4 +26,4 @@ SELECT ARRAY_REDUCE( -[ RECORD 1 ]----------------------------------- array_reduce([2, 3, 4], (acc, d) -> acc::Int32 * d::Int32): 24 -``` \ No newline at end of file +``` diff --git a/docs/en/sql-reference/20-sql-functions/10-semi-structured-functions/1-array/array-transform.md b/docs/en/sql-reference/20-sql-functions/10-semi-structured-functions/1-array/array-transform.md index 7fe4327e7c..17b6ec3cd1 100644 --- a/docs/en/sql-reference/20-sql-functions/10-semi-structured-functions/1-array/array-transform.md +++ b/docs/en/sql-reference/20-sql-functions/10-semi-structured-functions/1-array/array-transform.md @@ -6,7 +6,7 @@ import FunctionDescription from '@site/src/components/FunctionDescription'; -Transforms each element of a JSON array using a specified transformation Lambda expression. For more information about Lambda expression, see [Lambda Expressions](../../../00-sql-reference/42-lambda-expressions.md). +Transforms each element of a JSON array using a specified transformation Lambda expression. For more information about Lambda expression, see [Lambda Expressions](/sql/stored-procedure-scripting/#lambda-expressions). ## Syntax @@ -30,4 +30,4 @@ SELECT ARRAY_TRANSFORM( -[ RECORD 1 ]----------------------------------- array_transform([1, 2, 3, 4], data -> data::Int32 * 10): [10,20,30,40] -``` \ No newline at end of file +``` diff --git a/docs/en/sql-reference/20-sql-functions/10-semi-structured-functions/3-map/map-filter.md b/docs/en/sql-reference/20-sql-functions/10-semi-structured-functions/3-map/map-filter.md index 95d839ac92..8dd2fdf251 100644 --- a/docs/en/sql-reference/20-sql-functions/10-semi-structured-functions/3-map/map-filter.md +++ b/docs/en/sql-reference/20-sql-functions/10-semi-structured-functions/3-map/map-filter.md @@ -5,7 +5,7 @@ import FunctionDescription from '@site/src/components/FunctionDescription'; -Filters key-value pairs in a JSON object based on a specified condition, defined using a [lambda expression](../../../00-sql-reference/42-lambda-expressions.md). +Filters key-value pairs in a JSON object based on a specified condition, defined using a [lambda expression](/sql/stored-procedure-scripting/#lambda-expressions). ## Syntax @@ -29,4 +29,4 @@ SELECT MAP_FILTER('{"status":"active", "user":"admin", "time":"2024-11-01"}'::VA ├─────────────────────┤ │ {"status":"active"} │ └─────────────────────┘ -``` \ No newline at end of file +``` diff --git a/docs/en/sql-reference/20-sql-functions/10-semi-structured-functions/3-map/map-transform-keys.md b/docs/en/sql-reference/20-sql-functions/10-semi-structured-functions/3-map/map-transform-keys.md index a95dee9b20..b6bdebf1c4 100644 --- a/docs/en/sql-reference/20-sql-functions/10-semi-structured-functions/3-map/map-transform-keys.md +++ b/docs/en/sql-reference/20-sql-functions/10-semi-structured-functions/3-map/map-transform-keys.md @@ -5,7 +5,7 @@ import FunctionDescription from '@site/src/components/FunctionDescription'; -Applies a transformation to each key in a JSON object using a [lambda expression](../../../00-sql-reference/42-lambda-expressions.md). +Applies a transformation to each key in a JSON object using a [lambda expression](/sql/stored-procedure-scripting/#lambda-expressions). ## Syntax @@ -29,4 +29,4 @@ SELECT MAP_TRANSFORM_KEYS('{"name":"John", "role":"admin"}'::VARIANT, (k, v) -> ├──────────────────────────────────────┤ │ {"name_v1":"John","role_v1":"admin"} │ └──────────────────────────────────────┘ -``` \ No newline at end of file +``` diff --git a/docs/en/sql-reference/20-sql-functions/10-semi-structured-functions/3-map/map-transform-values.md b/docs/en/sql-reference/20-sql-functions/10-semi-structured-functions/3-map/map-transform-values.md index f4e70faa5e..15cd035ec1 100644 --- a/docs/en/sql-reference/20-sql-functions/10-semi-structured-functions/3-map/map-transform-values.md +++ b/docs/en/sql-reference/20-sql-functions/10-semi-structured-functions/3-map/map-transform-values.md @@ -5,7 +5,7 @@ import FunctionDescription from '@site/src/components/FunctionDescription'; -Applies a transformation to each value in a JSON object using a [lambda expression](../../../00-sql-reference/42-lambda-expressions.md). +Applies a transformation to each value in a JSON object using a [lambda expression](/sql/stored-procedure-scripting/#lambda-expressions). ## Syntax @@ -29,4 +29,4 @@ SELECT MAP_TRANSFORM_VALUES('{"a":1,"b":2}'::VARIANT, (k, v) -> v * 10) AS trans ├────────────────────┤ │ {"a":10,"b":20} │ └────────────────────┘ -``` \ No newline at end of file +``` diff --git a/docs/en/sql-reference/30-stored-procedure-scripting/_category_.json b/docs/en/sql-reference/30-stored-procedure-scripting/_category_.json new file mode 100644 index 0000000000..bb010dbbd1 --- /dev/null +++ b/docs/en/sql-reference/30-stored-procedure-scripting/_category_.json @@ -0,0 +1,4 @@ +{ + "label": "Stored Procedure & Scripting", + "position": 30 +} diff --git a/docs/en/sql-reference/30-stored-procedure-scripting/index.md b/docs/en/sql-reference/30-stored-procedure-scripting/index.md new file mode 100644 index 0000000000..9fb38dca63 --- /dev/null +++ b/docs/en/sql-reference/30-stored-procedure-scripting/index.md @@ -0,0 +1,632 @@ +--- +title: Stored Procedure & SQL Scripting +slug: /stored-procedure-scripting/ +--- + +Stored procedures in Databend let you package SQL logic that runs on the server with access to control flow, variables, cursors, and dynamic statements. This page explains how to create procedures and write the inline scripting that powers them. + +## Defining a Procedure + +```sql +CREATE [OR REPLACE] PROCEDURE ( , ...) +RETURNS [NOT NULL] +LANGUAGE SQL +[COMMENT = ''] +AS $$ +BEGIN + -- Declarations and statements + RETURN ; + -- Or return a query result + -- RETURN TABLE(); +END; +$$; +``` + +| Component | Description | +|-----------|-------------| +| `` | Identifier for the procedure. Schema qualification is optional. | +| ` ` | Input parameters typed with Databend scalar types. Parameters are passed by value. | +| `RETURNS [NOT NULL]` | Declares the logical return type. `NOT NULL` enforces a non-nullable response. | +| `LANGUAGE SQL` | Databend currently accepts `SQL` only. | +| `RETURN` / `RETURN TABLE` | Ends execution and provides either a scalar or tabular result. | + +Use [`CREATE PROCEDURE`](/sql/sql-commands/ddl/procedure/create-procedure) to persist the definition, [`CALL`](/sql/sql-commands/ddl/procedure/call-procedure) to run it, and [`DROP PROCEDURE`](/sql/sql-commands/ddl/procedure/drop-procedure) to remove it. + +### Minimal Example + +```sql +CREATE OR REPLACE PROCEDURE convert_kg_to_lb(kg DOUBLE) +RETURNS DOUBLE +LANGUAGE SQL +COMMENT = 'Converts kilograms to pounds' +AS $$ +BEGIN + RETURN kg * 2.20462; +END; +$$; + +CALL PROCEDURE convert_kg_to_lb(10); +``` + +## Language Basics Inside Procedures + +### Declare Section + +Stored procedures can start with an optional `DECLARE` block to initialize variables before the executable section. + +```sql +CREATE OR REPLACE PROCEDURE sp_with_declare() +RETURNS INT +LANGUAGE SQL +AS $$ +DECLARE + counter := 0; +BEGIN + counter := counter + 5; + RETURN counter; +END; +$$; + +CALL PROCEDURE sp_with_declare(); +``` + +The `DECLARE` section accepts the same definitions as `LET`, including `RESULTSET` and `CURSOR` declarations. Use a semicolon after each item. + +### Variables and Assignment + +Use `LET` to declare variables or constants, and reassign by omitting `LET`. + +```sql +CREATE OR REPLACE PROCEDURE sp_demo_variables() +RETURNS FLOAT +LANGUAGE SQL +AS $$ +BEGIN + LET total := 100; + LET rate := 0.07; + + total := total * rate; -- Multiply by the rate + total := total + 5; -- Reassign without LET + + RETURN total; +END; +$$; + +CALL PROCEDURE sp_demo_variables(); +``` + +### Variable Scope + +Variables are scoped to the enclosing block. Inner blocks can shadow outer bindings, and the outer value is restored when the block exits. + +```sql +CREATE OR REPLACE PROCEDURE sp_demo_scope() +RETURNS STRING +LANGUAGE SQL +AS $$ +BEGIN + LET threshold := 10; + LET summary := 'outer=' || threshold; + + IF threshold > 0 THEN + LET threshold := 5; -- Shadows the outer value + summary := summary || ', inner=' || threshold; + END IF; + + summary := summary || ', after=' || threshold; + RETURN summary; +END; +$$; + +CALL PROCEDURE sp_demo_scope(); +``` + +### Comments + +Procedures support single-line (`-- text`) and multi-line (`/* text */`) comments. + +```sql +CREATE OR REPLACE PROCEDURE sp_demo_comments() +RETURNS FLOAT +LANGUAGE SQL +AS $$ +BEGIN + -- Calculate price with tax + LET price := 15; + LET tax_rate := 0.08; + + /* + Multi-line comments are useful for documenting complex logic. + The following line returns the tax-inclusive price. + */ + RETURN price * (1 + tax_rate); +END; +$$; + +CALL PROCEDURE sp_demo_comments(); +``` + +### Lambda Expressions + +Lambda expressions define inline logic that can be passed to array functions or invoked within queries. They follow the ` -> ` form (wrap parameters in parentheses when more than one is provided). The expression can include casts, conditional logic, and even references to procedure variables. + +- Use `:variable_name` to reference procedure variables inside the lambda when it runs within a SQL statement. +- Functions such as `ARRAY_TRANSFORM` and `ARRAY_FILTER` evaluate the lambda for each element in the input array. + +```sql +CREATE OR REPLACE PROCEDURE sp_demo_lambda_array() +RETURNS STRING +LANGUAGE SQL +AS $$ +BEGIN + RETURN TABLE( + SELECT ARRAY_TRANSFORM([1, 2, 3, 4], item -> (item::Int + 1)) AS incremented + ); +END; +$$; + +CALL PROCEDURE sp_demo_lambda_array(); +``` + +Lambdas can also appear inside queries executed by the procedure. + +```sql +CREATE OR REPLACE PROCEDURE sp_demo_lambda_query() +RETURNS STRING +LANGUAGE SQL +AS $$ +BEGIN + RETURN TABLE( + SELECT + number, + ARRAY_TRANSFORM([number, number + 1], val -> (val::Int + 1)) AS next_values + FROM numbers(3) + ); +END; +$$; + +CALL PROCEDURE sp_demo_lambda_query(); +``` + +Capture procedure variables inside the lambda by prefixing them with `:` when the lambda runs in a SQL statement context. + +```sql +CREATE OR REPLACE PROCEDURE sp_lambda_filter() +RETURNS STRING +LANGUAGE SQL +AS $$ +BEGIN + LET threshold := 2; + RETURN TABLE( + SELECT ARRAY_FILTER([1, 2, 3, 4], element -> (element::Int > :threshold)) AS filtered + ); +END; +$$; + +CALL PROCEDURE sp_lambda_filter(); +``` + +You can also place complex expressions, such as `CASE` logic, inside the lambda body. + +```sql +CREATE OR REPLACE PROCEDURE sp_lambda_case() +RETURNS STRING +LANGUAGE SQL +AS $$ +BEGIN + RETURN TABLE( + SELECT + number, + ARRAY_TRANSFORM( + [number - 1, number, number + 1], + val -> (CASE WHEN val % 2 = 0 THEN 'even' ELSE 'odd' END) + ) AS parity_window + FROM numbers(3) + ); +END; +$$; + +CALL PROCEDURE sp_lambda_case(); +``` + +## Control Flow + +### IF Statements + +Use `IF ... ELSEIF ... ELSE ... END IF;` to branch inside a procedure. + +```sql +CREATE OR REPLACE PROCEDURE sp_evaluate_score(score INT) +RETURNS STRING +LANGUAGE SQL +AS $$ +BEGIN + IF score >= 90 THEN + RETURN 'Excellent'; + ELSEIF score >= 70 THEN + RETURN 'Good'; + ELSE + RETURN 'Review'; + END IF; +END; +$$; + +CALL PROCEDURE sp_evaluate_score(82); +``` + +### CASE Expressions + +`CASE` expressions provide an alternative to nested `IF` statements. + +```sql +CREATE OR REPLACE PROCEDURE sp_membership_discount(level STRING) +RETURNS FLOAT +LANGUAGE SQL +AS $$ +BEGIN + RETURN CASE + WHEN level = 'gold' THEN 0.2 + WHEN level = 'silver' THEN 0.1 + ELSE 0 + END; +END; +$$; + +CALL PROCEDURE sp_membership_discount('silver'); +``` + +### Range `FOR` + +Range-based loops iterate from a lower bound to an upper bound (inclusive). Use the optional `REVERSE` keyword to walk the range backwards. + +```sql +CREATE OR REPLACE PROCEDURE sp_sum_range(start_val INT, end_val INT) +RETURNS INT +LANGUAGE SQL +AS $$ +BEGIN + LET total := 0; + FOR i IN start_val TO end_val DO + total := total + i; + END FOR; + RETURN total; +END; +$$; + +CALL PROCEDURE sp_sum_range(1, 5); +``` + +Range loops require the lower bound to be less than or equal to the upper bound when stepping forward. + +```sql +CREATE OR REPLACE PROCEDURE sp_reverse_count(start_val INT, end_val INT) +RETURNS STRING +LANGUAGE SQL +AS $$ +BEGIN + LET output := ''; + FOR i IN REVERSE start_val TO end_val DO + output := output || i || ' '; + END FOR; + RETURN TRIM(output); +END; +$$; + +CALL PROCEDURE sp_reverse_count(1, 5); +``` + +#### `FOR ... IN` Queries + +Iterate directly over the result of a query. The loop variable exposes columns as fields. + +```sql +CREATE OR REPLACE PROCEDURE sp_sum_query(limit_rows INT) +RETURNS BIGINT +LANGUAGE SQL +AS $$ +BEGIN + LET total := 0; + FOR rec IN SELECT number FROM numbers(:limit_rows) DO + total := total + rec.number; + END FOR; + RETURN total; +END; +$$; + +CALL PROCEDURE sp_sum_query(5); +``` + +`FOR` can also iterate over previously declared result-set variables or cursors (see [Working with Query Results](#working-with-query-results)). + +### `WHILE` + +```sql +CREATE OR REPLACE PROCEDURE sp_factorial(n INT) +RETURNS INT +LANGUAGE SQL +AS $$ +BEGIN + LET result := 1; + WHILE n > 0 DO + result := result * n; + n := n - 1; + END WHILE; + RETURN result; +END; +$$; + +CALL PROCEDURE sp_factorial(5); +``` + +### `REPEAT` + +```sql +CREATE OR REPLACE PROCEDURE sp_repeat_sum(limit_val INT) +RETURNS INT +LANGUAGE SQL +AS $$ +BEGIN + LET counter := 0; + LET total := 0; + + REPEAT + counter := counter + 1; + total := total + counter; + UNTIL counter >= limit_val END REPEAT; + + RETURN total; +END; +$$; + +CALL PROCEDURE sp_repeat_sum(3); +``` + +### `LOOP` + +```sql +CREATE OR REPLACE PROCEDURE sp_retry_counter(max_attempts INT) +RETURNS INT +LANGUAGE SQL +AS $$ +BEGIN + LET retries := 0; + LOOP + retries := retries + 1; + IF retries >= max_attempts THEN + BREAK; + END IF; + END LOOP; + + RETURN retries; +END; +$$; + +CALL PROCEDURE sp_retry_counter(5); +``` + +### Break and Continue + +Use `BREAK` to exit a loop early and `CONTINUE` to skip to the next iteration. + +```sql +CREATE OR REPLACE PROCEDURE sp_break_example(limit_val INT) +RETURNS INT +LANGUAGE SQL +AS $$ +BEGIN + LET counter := 0; + LET total := 0; + + WHILE TRUE DO + counter := counter + 1; + IF counter > limit_val THEN + BREAK; + END IF; + IF counter % 2 = 0 THEN + CONTINUE; + END IF; + total := total + counter; + END WHILE; + + RETURN total; +END; +$$; + +CALL PROCEDURE sp_break_example(5); +``` + +Use `BREAK