QUERY
On this page
SingleStore Helios Procedural SQL (PSQL) supports the QUERY
data type, whose value represents a SQL SELECT
statement, optionally with bound variable values.
Query type values may be returned from a stored procedure, assigned as a value into a variable, passed as a parameter to a stored procedure, evaluated to return a rowset to a client using ECHO, or evaluated using COLLECT or SCALAR functions.
TO_SELECT
statement to a query type.
Query Type Definition Syntax
The following syntax declares a query type value.
name QUERY(field_definition [, ...]) [ = select_statement]
field_definition:
field_name data_type [data_type_modifier]
Arguments
name
The name of the query variable or parameter.
field_
A query type declaration will contain one or more field_
s.
The number of field_
s must be the same as the number of columns that the select_
will return.
The data_
s in the field_
s do not have to be the same as the data types of the columns that the select_
will return.:>
operator will automatically be used to convert the column type to the field type.
Field names specified in the select_
are irrelevant; The field_
s in the field_
are instead used in the QUERY’s result set.
field_
The name of the field.
data_
Any scalar-valued data type.
data_
If not present or NULL
, indicates that field_NULL
values in the QUERY’s result set.
If NOT NULL
, indicates that field_NULL
values in the QUERY’s result set.
select_
A SQL SELECT
statement, optionally referencing parameters and variables from the current stored procedure.SELECT
statement is built dynamically using a string, the string should be passed to TO_TO_
will convert the string to a query type value.
The select_
is optional because it does not need to be specified when the QUERY is declared.select_
may be assigned to the query variable at a later time.
Remarks
After a query variable has been declared, new fields cannot be added and existing fields cannot be changed.
When calling a procedure, input parameters and return types are always passed by value.
Declaration and Initialization
Query types are declared in a procedure as either an input parameter or as a variable in the DECLARE
block.
DELIMITER //CREATE OR REPLACE PROCEDURE p(x QUERY(a INT, b VARCHAR(30))) -- x is a query type parameterRETURNS QUERY(a INT, b VARCHAR(30)) ASDECLARE-- q is a query type variableq QUERY(a INT, b VARCHAR(30)) = SELECT 1, "red";BEGINIF rand() > 0.5 THENRETURN q;END IF;RETURN x;END //DELIMITER ;
Assignment
You may assign a value to a query type variable in the declaration of the variable using =
, or :=
.SELECT
statement, a query variable, or a query parameter.=
or :=
.
Query Type Example
The following example demonstrates how to pass a query as an input parameter to a procedure, assign a query result from a stored procedure into a query type variable, and conditionally assign different values into a query type variable.
DELIMITER //CREATE OR REPLACE PROCEDURE p(x QUERY(a INT, b VARCHAR(30)),a INT)RETURNS QUERY(a INT, b VARCHAR(30)) ASDECLAREq QUERY(a INT, b VARCHAR(30)) = SELECT 1, "purple";BEGINIF a = 0 THENRETURN q;ELSERETURN x;END IF;END //CREATE OR REPLACE PROCEDURE q(i INT)RETURNS QUERY(a INT, b VARCHAR(30)) ASDECLAREv QUERY(a INT, b VARCHAR(30)) = SELECT 2, "yellow";l QUERY(a INT, b VARCHAR(30)) = SELECT null, null;BEGINl = p(v, i);RETURN l;END //DELIMITER ;ECHO q(0);+------+--------+| a | b |+------+--------+| 1 | purple |+------+--------+ECHO q(1);+------+--------+| a | b |+------+--------+| 2 | yellow |+------+--------+
Binding Variables to a Query Type Value
Query variable and parameter values may include both a query statement as well as bindings of variables.QUERY
variable types can be bound.
CREATE TABLE t(a INT, b VARCHAR(30));INSERT t VALUES(1, "red"), (2, "blue"), (3, "green");DELIMITER //CREATE OR REPLACE PROCEDURE p2(n INT)RETURNS QUERY(a INT, b VARCHAR(30)) ASDECLARE q QUERY(a INT, b VARCHAR(30)) = SELECT a, b FROM t WHERE t.a >= n;BEGINRETURN q;END //DELIMITER ;
ECHO p2(1);
+------+-------+
| a | b |
+------+-------+
| 3 | green |
| 2 | blue |
| 1 | red |
+------+-------+
ECHO p2(2);
+------+-------+
| a | b |
+------+-------+
| 3 | green |
| 2 | blue |
+------+-------+
In the first call to p2
, the query returned is
SELECT a, b FROM t WHERE t.a >= 1
which produces 3 rows of output.p2
, the query returned is
SELECT a, b FROM t WHERE t.a >= 2
which produces 2 rows of output.a
at the time of the call is bound into the query prior to returning the query.
Late Binding
PSQL performs late binding of queries assigned to query type variables or returned by stored procedures.ECHO
call, or by use of the functions SCALAR
or COLLECT
.
Capture Semantics
QUERY
type variables use the original value of each stored procedure variable they reference.QUERY
will be the value that the variable had at QUERY
type variable creation time, not QUERY
type variable execution time.
Using Query Type Values In Queries
You can use query type values in other queries similar to the way you would reference a view.
For example, the stored procedure defined below declares query type variable q
and uses it in an INSERT .
statement to add data to the table called target
.
CREATE TABLE source(a int, b int);CREATE TABLE target(a int, b int);INSERT INTO source VALUES(1, 2), (2, 2), (3, 2), (4, 3), (5, 3);DELIMITER //CREATE OR REPLACE PROCEDURE p() ASDECLAREq QUERY(a int, b int) = SELECT a, b FROM source WHERE b = 2;BEGININSERT INTO target SELECT a, b from q;END //DELIMITER ;CALL p();SELECT * FROM target;
+------+------+
| a | b |
+------+------+
| 1 | 2 |
| 2 | 2 |
| 3 | 2 |
+------+------+
In the example above, notice that the query type variable q
is used in the FROM
clause.
DELIMITER //CREATE OR REPLACE PROCEDURE p() ASDECLAREq QUERY(a int, b int) = SELECT a, b FROM source;BEGINECHO SELECT * FROM q WHERE a < 3 ORDER BY a ASC;END //DELIMITER ;call p();
+------+------+
| a | b |
+------+------+
| 1 | 2 |
| 2 | 2 |
+------+------+
You can also assign values to query type variables in the body of a stored procedure, instead of the DECLARE block.
CREATE TABLE t(a int, b int);INSERT t VALUES(1,2),(3,4),(5,6);DELIMITER //CREATE OR REPLACE PROCEDURE ptest(x INT) ASDECLAREq QUERY(a INT, b INT);BEGINIF x < 0 THENq = SELECT a, b FROM t;ELSEq = SELECT a, b FROM t WHERE a = x;END IF;echo SELECT a, b FROM q;END //DELIMITER ;CALL ptest(1);
+------+------+
| a | b |
+------+------+
| 1 | 2 |
+------+------+
CALL ptest(-1);
+------+------+
| a | b |
+------+------+
| 3 | 4 |
| 5 | 6 |
| 1 | 2 |
+------+------+
Database Binding Behavior for QTVs Within a Stored Procedure
If a database is not specified in a QTV within a stored procedure, the query uses the database that the stored procedure was defined in.
The following example explains this behavior.
CREATE DATABASE db_test1;CREATE DATABASE db_test2;CREATE DATABASE db_test3;CREATE TABLE db_test1.tmp(val INT);INSERT INTO db_test1.tmp VALUES (1),(2);CREATE TABLE db_test2.tmp(val INT);INSERT INTO db_test2.tmp VALUES (3),(4);CREATE TABLE db_test3.tmp(val INT);INSERT INTO db_test3.tmp VALUES (5),(6);DELIMITER //CREATE OR REPLACE PROCEDURE db_test3.sp() ASDECLAREq QUERY(val INT) = SELECT * FROM tmp;p QUERY(val INT) = SELECT SUM(val) FROM db_test1.tmp;BEGINECHO SELECT * FROM q;ECHO SELECT * FROM p;END //DELIMITER ;
Change the context database to db_
and call the stored procedure.
USE db_test1;CALL db_test3.sp();
+------+
| val |
+------+
| 5 |
| 6 |
+------+
2 rows in set (0.01 sec)
+------+
| val |
+------+
| 3 |
+------+
1 row in set (0.01 sec)
Now, change the context database to db_
and call the stored procedure.
USE db_test2;CALL db_test3.sp();
+------+
| val |
+------+
| 5 |
| 6 |
+------+
2 rows in set (0.01 sec)
+------+
| val |
+------+
| 3 |
+------+
1 row in set (0.28 sec)
Instead of using the currently selected database (specified with USE
), the query SELECT * FROM tmp;
uses the definer’s database (the database specified while defining the stored procedure).
Related Topics
Last modified: June 12, 2023