Control Flow Statements
On this page
This topic describes the syntax to define logical control flow in SingleStore Procedural SQL (PSQL) for stored procedures and user-defined scalar-valued functions (UDFs).
-
Conditional Control
-
Iterative Control
Statement Blocks
Statement blocks optionally declare variables, then enclose one or more statements, and optionally handle exceptions.
When executed, the statements in the statement_
portion of the block are processed sequentially.statement_
must be terminated with a semicolon (;
).
Statement blocks can be nested.
Syntax
[ DECLARE variable_list ] [ ...n ]BEGINstatement_list[ EXCEPTIONwhen_clause_list ]END
Arguments
variable_
A variable definition or series of definitions.DECLARE
keywords may appear, each with its own variable_
.
statement_
Any valid procedural SQL statement or series of statements.
when_
The when_
defines different possible exception conditions and statements to handle them.
Examples
The following example adds one to the input integer and returns the result.
DELIMITER //CREATE FUNCTION plus_one(a INT) RETURNS INT ASDECLAREb INT = a;BEGINb += 1;RETURN b;END //DELIMITER ;
SELECT plus_one(1);
+-------------+
| plus_one(1) |
+-------------+
| 2 |
+-------------+
The example below illustrates nested statement blocks, and the general syntax of the DECLARE
statements at the beginning of a block.
DELIMITER //CREATE OR REPLACE FUNCTION nesting(i INT) RETURNS BIGINT ASDECLARE x INT = 0;DECLARE z1 INT; z2 VARCHAR(255);BEGINDECLARE q INT = 0;BEGINIF q = i THENDECLARE xx INT = 7;BEGINRETURN q + xx;END;ELSEDECLARE q2 INT = 88;BEGINRETURN q2;END;END IF;END;END //DELIMITER ;
SELECT nesting(0);
+------------+
| nesting(0) |
+------------+
| 7 |
+------------+
SELECT nesting(1);
+------------+
| nesting(1) |
+------------+
| 88 |
+------------+
IF … THEN … END IF
Specifies one or more statements to be executed if a given boolean expression evaluates to TRUE
.IF
blocks must be terminated with the END IF
keyword pair.
Syntax
IF boolean_expression THEN
statement_list
END IF;
Arguments
boolean_
An expression that evaluates to TRUE
or FALSE
.TRUE
, the statement_THEN .
will be executed.FALSE
, the statement_
statement_
Any valid procedural SQL statement or series of statements.
Example
The following example returns a boolean value (1
for TRUE
and 0
for FALSE
) if the input integer is odd.
DELIMITER //CREATE FUNCTION is_odd(a INT) RETURNS BOOL ASBEGINIF a % 2 = 0 THENRETURN FALSE;END IF;RETURN TRUE;END //DELIMITER ;
SELECT is_odd(5);
+-----------+
| is_odd(5) |
+-----------+
| 1 |
+-----------+
IF … THEN … ELSE … END IF
Specifies a condition and two alternative lists of statements to execute, depending on whether the condition is true.IF
blocks must be terminated with the END IF
keyword pair.
Syntax
IF boolean_expression THEN
statement_list
ELSE
statement_list
END IF;
Arguments
boolean_
An expression that evaluates to TRUE
or FALSE
.TRUE
, the statement_THEN .
will be executed.FALSE
, the statement_ELSE
will be executed instead.
statement_
Any valid procedural SQL statement or series of statements.
Example
The following example returns a boolean value (1
for TRUE
and 0
for FALSE
) if the input integer is odd.
DELIMITER //CREATE FUNCTION is_odd(a INT) RETURNS BOOL ASDECLAREresult BOOL;BEGINIF a % 2 = 0 THENresult = FALSE;ELSEresult = TRUE;END IF;RETURN result;END //DELIMITER ;
SELECT is_odd(3);
+-----------+
| is_odd(3) |
+-----------+
| 1 |
+-----------+
IF … THEN … ELSIF … THEN … END IF
Specifies one or more statements to be executed if an initial boolean expression evaluates to TRUE
.FALSE
, one or more ELSIF
boolean expressions are evaluated.ELSIF
expression evaluates to TRUE
, its statement list will be executed, and no additional ELSIF
expressions will be evaluated.
An optional ELSE
clause can also be specified after a block of ELSIF
statements.ELSE
clause evaluates to TRUE
, then the list of statements in the ELSE
clause are executed.
All IF
blocks must be terminated with the END IF
keyword pair.
Syntax
IF boolean_expression THEN
statement_list
ELSIF boolean_expression THEN
statement_list
[...n]
[ELSE
statement_list
]
END IF;
Arguments
boolean_
An expression that evaluates to TRUE
or FALSE
.
statement_
Any valid procedural SQL statement or series of statements.
Example
The following example accepts a test score as an integer and outputs a grade letter.
DELIMITER //CREATE FUNCTION test_grade(test_score INT) RETURNS CHAR(1) ASDECLAREgrade_letter CHAR(1);BEGINIF test_score >= 90 THENgrade_letter = 'A';ELSIF test_score >= 80 THENgrade_letter = 'B';ELSIF test_score >= 70 THENgrade_letter = 'C';ELSIF test_score >= 60 THENgrade_letter = 'D';ELSEgrade_letter = 'F';END IF;RETURN grade_letter;END //DELIMITER ;
SELECT test_grade(89);
+----------------+
| test_grade(89) |
+----------------+
| B |
+----------------+
LOOP … END LOOP
Specifies one or more statements to execute repeatedly in an infinite loop.IF .
.
Syntax
LOOP
statement_list
END LOOP;
Arguments
statement_
Any valid procedural SQL statement or series of statements.
Example
The following example creates an endless loop that adds one to the input integer.RETURN
statement will never get reached.
DELIMITER //CREATE FUNCTION endless_loop(a INT) RETURNS INT ASDECLAREb INT = a;BEGINLOOPb += 1;END LOOP;RETURN b;END //DELIMITER ;
EXIT and EXIT WHEN
Terminates the current iteration of a loop and then exits the loop body, and optionally when a boolean condition is met.EXIT
and EXIT WHEN
can be used in any loop body, including LOOP
, FOR .
, or WHILE .
.
Syntax
{ [FOR | WHILE ] expression } LOOP
[statement_list]
{ EXIT | EXIT WHEN boolean_condition } [loop_label] ;
END LOOP;
Arguments
expression
Any expression associated with the loop declaration, such as a conditional boolean expression.
statement_
Any valid procedural SQL statement or series of statements.
boolean_
An expression that evaluates to TRUE
or FALSE
.TRUE
, the statement_EXIT
will be executed.FALSE
, loop will continue iterating until the boolean expression evaluates to TRUE
.
loop_
The optional identifier for a parent loop.EXIT
with a loop label, the label must be set on one of the parent loops.
Examples
IF … THEN … EXIT Example
The following example generates text of the minimum specified length, and uses an EXIT
statement in the body of a loop to return the result when the boolean condition is met.
DELIMITER //CREATE FUNCTION text_generator(min_length INT) RETURNS TEXT ASDECLARElorem_text TEXT = "Lorem ipsum dolor sit amet. ";result TEXT = lorem_text;BEGINLOOPIF LENGTH(result) < min_length THENresult = CONCAT(result, lorem_text);ELSEEXIT;END IF;END LOOP;RETURN result;END //DELIMITER ;
SELECT text_generator(50);
+----------------------------------------------------------+
| text_generator(50) |
+----------------------------------------------------------+
| Lorem ipsum dolor sit amet. Lorem ipsum dolor sit amet. |
+----------------------------------------------------------+
EXIT WHEN Example
The following example is similar to the LOOP .
example and generates text of the minimum specified length.WHEN
expression, the loop is exited.
DELIMITER //CREATE FUNCTION text_generator(min_length INT) RETURNS TEXT ASDECLARElorem_text TEXT = "Lorem ipsum dolor sit amet. ";result TEXT = lorem_text;BEGINLOOPEXIT WHEN LENGTH(result) >= min_length;result = CONCAT(result, lorem_text);END LOOP;RETURN result;END //DELIMITER ;
SELECT text_generator(50);
+----------------------------------------------------------+
| text_generator(50) |
+----------------------------------------------------------+
| Lorem ipsum dolor sit amet. Lorem ipsum dolor sit amet. |
+----------------------------------------------------------+
WHILE … LOOP … END LOOP
Specifies an initial boolean condition and a list of statements.TRUE
, the loop will begin execution of the statement list.FALSE
, the loop will immediately exit.
Syntax
WHILE boolean_expression LOOP
statement_list
END LOOP;
Arguments
boolean_
An expression that evaluates to TRUE
or FALSE
.
statement_
Any valid procedural SQL statement or series of statements.
Example
The following example is similar to the LOOP .
and LOOP .
examples, and generates text of the minimum specified length.
DELIMITER //CREATE FUNCTION text_generator(min_length INT) RETURNS TEXT ASDECLARElorem_text TEXT = "Lorem ipsum dolor sit amet. ";result TEXT = lorem_text;BEGINWHILE LENGTH(result) < min_length LOOPresult = CONCAT(result, lorem_text);END LOOP;RETURN result;END //DELIMITER ;
SELECT text_generator(50);
+----------------------------------------------------------+
| text_generator(50) |
+----------------------------------------------------------+
| Lorem ipsum dolor sit amet. Lorem ipsum dolor sit amet. |
+----------------------------------------------------------+
FOR … LOOP … END LOOP
Specifies a loop with a fixed number of iterations using either the size of an array or a range of integer values as the iteration scheme.FOR
loops support reverse iteration using the REVERSE
keyword and explicit loop strides by specifying an integer value with the BY
keyword.
Syntax
Array Range FOR Loop Syntax
FOR counter_variable IN array_expression LOOP
statement_list
END LOOP;
Integer Range FOR Loop Syntax
FOR counter_variable IN [REVERSE]
lower_bound .. upper_bound [BY stride_count] LOOP
statement_list
END LOOP;
Arguments
counter_
A variable that is scoped to the body of the FOR
loop and must be unique within this scope.
array_
An array expression that references an initialized array with a defined length.
lower_
An expression that evaluates to an integer value, which represents the lower bound (starting value) of the iteration scheme.
upper_
An expression that evaluates to an integer value, which represents the upper bound (ending value) of the iteration scheme.
stride_
An expression that evaluates to an integer value, which increments the current iteration count by the specified amount after the statement list in the loop body has been executed.
statement_
Any valid procedural SQL statement or series of statements.
Remarks
When using a FOR
loop on a variable that references an array, the loop creates a read-only copy of the array and uses it as the iteration scheme.
DELIMITER //CREATE FUNCTION array_modification() RETURNS VARCHAR(255) ASDECLAREmyarray ARRAY(INT) = [1, 2, 3];loop_count INT = 0;BEGINFOR i IN myarray LOOPmyarray = [1, 2, 3, 4];loop_count += 1;END LOOP;RETURN CONCAT("loop_count = ", loop_count,", myarray size = ", LENGTH(myarray));END //DELIMITER ;
This example declares an myarray
with a size of 3, then loops over the array.myarray
value is changed.myarray
is updated to the new value with a length of 4.
SELECT array_modification();
+----------------------------------+
| array_modification() |
+----------------------------------+
| loop_count = 3, myarray size = 4 |
+----------------------------------+
Examples
FOR Loop on Array Range Example
The following example declares an array and then loops over the array to count its size:
DELIMITER //CREATE FUNCTION count_array() RETURNS INT ASDECLAREmyarray ARRAY(INT) = [1, 2, 3];count INT = 0;BEGINFOR i IN myarray LOOPcount += 1;END LOOP;RETURN count;END //DELIMITER ;
SELECT count_array();
+---------------+
| count_array() |
+---------------+
| 3 |
+---------------+
FOR Loop on Integer Range Example
The following example uses a FOR
loop to computes the factorial of the input integer and returns it.
DELIMITER //CREATE FUNCTION factorial(num INT) RETURNS INT ASDECLAREfactor INT = 1;BEGINFOR i IN 1 .. num LOOPfactor = factor * i;END LOOP;RETURN factor;END //DELIMITER ;
SELECT factorial(5);
+--------------+
| factorial(5) |
+--------------+
| 120 |
+--------------+
Reverse FOR Loop Example
The following example uses a reversed FOR
loop to count down from the specified input number and returns a text string.REVERSE
is specified.
DELIMITER //CREATE FUNCTION countdown(num INT) RETURNS VARCHAR(255) ASDECLAREoutput VARCHAR(255) = "Countdown: ";BEGINFOR i IN REVERSE num .. 1 LOOPoutput = CONCAT(output, i, ", ");END LOOP;output = CONCAT(output, "Launch!");RETURN output;END //DELIMITER ;
SELECT countdown(10);
+---------------------------------------------------+
| countdown(10) |
+---------------------------------------------------+
| Countdown: 10, 9, 8, 7, 6, 5, 4, 3, 2, 1, Launch! |
+---------------------------------------------------+
FOR Loop with Stride Length
The following example uses a reverse loop with a stride length of 2 to count down from the input integer and output each even number.
DELIMITER //CREATE OR REPLACE FUNCTION countdown_evens(num INT) RETURNS VARCHAR(255) ASDECLAREoutput VARCHAR(255) = "Countdown Evens: ";start INT = num;BEGINIF num % 2 = 1 THENstart = start - 1;END IF;output = CONCAT(output, start);start = start - 2;FOR i IN REVERSE start .. 2 BY 2 LOOPoutput = CONCAT(output, ", ", i);END LOOP;RETURN output;END //DELIMITER ;
SELECT countdown_evens(11);
+---------------------------------+
| countdown_evens(11) |
+---------------------------------+
| Countdown Evens: 10, 8, 6, 4, 2 |
+---------------------------------+
Loop Labels
Loops can be labeled using unique identifier syntax, which makes it easier to identify a specific loop in a series of nested loops.LOOP
keyword, but optionally be labeled after the terminating END LOOP
keyword pair.
Loop labels can be used to terminate any loop within the scope of a nested loop by using an EXIT
statement.CONTINUE
statement for conditional loops to return control to the initial conditional expression.
Syntax
<<label_name>>
{ WHILE boolean_expression LOOP | LOOP }
statement_list
END LOOP [label_name];
Arguments
label_
An identifier for the loop, enclosed by double angle brackets (<<
and >>
) for the initial declaration.
boolean_
An expression that evaluates to TRUE
or FALSE
.
statement_
Any valid procedural SQL statement or series of statements.
Examples
Loops Labels with EXIT
The following example demonstrates loop labels for EXIT
statements by creating a nested loop where the outer loop is named parent
and the inner loop is named child
.
DELIMITER //CREATE FUNCTION parent_child_loop(a INT) RETURNS INT ASDECLAREb INT = a;BEGIN<<parent>>LOOP<<child>>LOOPEXIT parent WHEN a >= 100;b += 1;END LOOP child;RETURN 200;END LOOP parent;RETURN b;END //DELIMITER ;
When this function is executed, the outer loop’s RETURN
statement is never reached.EXIT parent
statement is executed when the input value meets or exceeds 100:
SELECT parent_child_loop(1);
+----------------------+
| parent_child_loop(1) |
+----------------------+
| 100 |
+----------------------+
Loop Labels with CONTINUE
The following example demonstrates loop labels for CONTINUE
statements by creating a single WHILE
loop.
DELIMITER //CREATE FUNCTION continue_loop_label(a INT) RETURNS INT ASDECLAREb INT = a;BEGIN<<myloop>>WHILE b < 10 LOOPb += 1;CONTINUE myloop;EXIT myloop;END LOOP myloop;RETURN b;END //DELIMITER ;
When this function is executed, the EXIT myloop
statement is never reached because the preceding CONTINUE myloop
statement forces return of control to the loop’s initial conditional statement: WHILE a < 10 LOOP
.
SELECT continue_loop_label(1);
+------------------------+
| continue_loop_label(1) |
+------------------------+
| 10 |
+------------------------+
CONTINUE and CONTINUE WHEN
Forces return of control to the top of a loop’s conditional expression or specifies its own conditional expression where, if satisfied, returns control to the top of the loop.CONTINUE
syntax can be used in the following ways:
-
CONTINUE loop_
in a labeledlabel WHILE boolean_
, where theexpression LOOP CONTINUE
statement returns control to the top of theWHILE
loop. -
CONTINUE WHEN boolean_
in aexpression LOOP
, where any statements following theCONTINUE
statement will not be executed.Instead, control will be returned to the top of the loop.
See the examples below for more information.
Syntax
[<<label_name>>]
{ WHILE boolean_expression LOOP | LOOP }
statement_list
{ CONTINUE WHEN boolean_expression | CONTINUE label_name }
END LOOP [label_name];
Arguments
label_
An identifier for the loop, enclosed by double angle brackets (<<
and >>
) for the initial declaration.
boolean_
An expression that evaluates to TRUE
or FALSE
.
statement_
Any valid procedural SQL statement or series of statements.
Examples
CONTINUE for Labeled Loop
The following example demonstrates a CONTINUE
statement used inside of a labeled WHILE
loop.
DELIMITER //CREATE FUNCTION continue_labeled_example(a INT) RETURNS INT ASDECLAREb INT = a;BEGIN<<myloop>>WHILE b < 10 LOOPb += 1;CONTINUE myloop;EXIT myloop;END LOOP myloop;RETURN b;END //DELIMITER ;
When this function is executed, the EXIT myloop
statement is never reached because the preceding CONTINUE myloop
statement forces return of control to the loop’s initial conditional statement: WHILE a < 10 LOOP
.
SELECT continue_labeled_example(1);
+-----------------------------+
| continue_labeled_example(1) |
+-----------------------------+
| 10 |
+-----------------------------+
CONTINUE WHEN for a Non-Labeled Loop
The following example demonstrates loop labels for CONTINUE
statements by creating a single loop.
DELIMITER //CREATE OR REPLACE FUNCTION continue_when_example() RETURNS INT ASDECLAREa INT = 0;b INT = 0;BEGINLOOPa += 1;CONTINUE WHEN a < 10;b += 1;EXIT WHEN b > 20;END LOOP;RETURN a;END //DELIMITER ;
In this example, the CONTINUE WHEN
statement forces return of control to the top of the loop until the value of a
is greater than or equal to 10.a
’s value reaches 10, the b += 1
statement will be executed until the exit condition is met.
SELECT continue_when_example();
+-------------------------+
| continue_when_example() |
+-------------------------+
| 30 |
+-------------------------+
Last modified: June 12, 2023