COLLECT
On this page
The COLLECT
function executes a SELECT
statement having the QUERY type and stores the result as an array of records.
After COLLECT
executes you will typically iterate through the array to perform processing on its elements.
Syntax
variable_name = COLLECT(query_type_value)
variable_name = COLLECT(select_statement, QUERY(field_definition [, ...]))
field_definition:
field_name data_type [data_type_modifier]
Arguments
query_
A query type value.
field_
The number of fields in the field_
must be the same as the number of columns that the select_
will return.data_
(s) in the field_
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_
(s) in the field_
also need not be the same as the field names in the select_
.
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 resulting array.
If NOT NULL
, indicates that field_NULL
values in the resulting array.
select_
A string containing a SQL SELECT
statement.
Remarks
Some database systems implement cursors, which allow programmers to iterate through each row of a recordset and perform an action on the row.cursor.
However, you can achieve read-only cursor functionality by calling COLLECT
and iterating over the values in the resulting array.
Expressions of the form record.
for a record type value cannot be substituted directly into a SQL statement in a stored procedure._
and _
.
Example 1: Using COLLECT
with Static Queries
In the following example, COLLECT
uses a query type variable, whose definition SELECT * from t
is static.
DROP DATABASE IF EXISTS singlestore_docs_example;CREATE DATABASE singlestore_docs_example;USE singlestore_docs_example;CREATE TABLE t(id INT, name TEXT);CREATE TABLE output_log(msg TEXT);INSERT INTO t VALUES (1, 'red'), (2, 'green'), (3, 'blue');DELIMITER //CREATE OR REPLACE PROCEDURE p() ASDECLAREqry QUERY(id INT, name TEXT) = SELECT id, name FROM t;arr ARRAY(RECORD(id INT, name TEXT));_id INT;_name TEXT;BEGINarr = COLLECT(qry);FOR x in arr LOOP_id = x.id;_name = x.name;INSERT INTO output_log VALUES(CONCAT('[', _id, ', ', _name, ']'));END LOOP;END //DELIMITER ;CALL p();SELECT * FROM output_log ORDER BY msg;
+------------+
| msg |
+------------+
| [1, red] |
| [2, green] |
| [3, blue] |
+------------+
Note
Instead of using variable assignments and verbose definitions, you can shorten the procedure definition (and body) by inserting the COLLECT
function directly inside the loop as:
DELIMITER //CREATE OR REPLACE PROCEDURE p() ASDECLAREqry QUERY(id INT, name TEXT) = SELECT id, name FROM t;BEGINFOR x IN COLLECT(qry) LOOPINSERT INTO output_log VALUES(CONCAT('[', x.id, ', ', x.name, ']'));END LOOP;END //DELIMITER ;
The next example demonstrates the use of this style of code.
Example 2: Using COLLECT
with Dynamic Queries (Method 1)
Here, you call COLLECT
using a query type variable, whose value is populated by the TO_
function.TO_
allows you to write dynamic queries.
Warning
The TO_
function does not parameterize dynamic SQL queries, which results in unique plans being added to the in-memory and on-disk plancache.
If you need to define a query-type variable from a static query that use stored procedure parameters (e.SELECT t.
with x
being the input parameter value), you can do that directly instead of using TO_
.
DROP DATABASE IF EXISTS singlestore_docs_example;CREATE DATABASE singlestore_docs_example;USE singlestore_docs_example;CREATE TABLE t1(id INT, name TEXT);CREATE TABLE t2(id INT, name TEXT);CREATE TABLE output_log(msg TEXT);INSERT INTO t1 VALUES (1, 'red'), (2, 'green'), (3, 'blue');INSERT INTO t2 VALUES (1, 'orange'), (2, 'blue'), (3, 'purple');DELIMITER //CREATE OR REPLACE PROCEDURE p (tbl TEXT) ASDECLAREqry QUERY(id INT, name TEXT) = TO_QUERY(CONCAT('SELECT id, name FROM ' , tbl));BEGINFOR x IN COLLECT(qry) LOOPINSERT INTO output_log VALUES(CONCAT('[', x.id, ', ', x.name, ']'));END LOOP;END //DELIMITER ;CALL p('t2');SELECT * FROM output_log ORDER BY msg;
+-------------+
| msg |
+-------------+
| [1, orange] |
| [2, blue] |
| [3, purple] |
+-------------+
Example 3: Using COLLECT
with Dynamic Queries (Method 2)
Here, you specify a dynamic query directly in a COLLECT
statement.QUERY
type which specifies the output schema of the query, so it is known at the time the COLLECT
expression is compiled.
DROP DATABASE IF EXISTS singlestore_docs_example;CREATE DATABASE singlestore_docs_example;use singlestore_docs_example;CREATE TABLE t1(id INT, name TEXT);CREATE TABLE t2(id INT, name TEXT);CREATE TABLE output_log(msg TEXT);INSERT INTO t1 VALUES (1, 'red'), (2, 'green'), (3, 'blue');INSERT INTO t2 VALUES (1, 'orange'), (2, 'blue'), (3, 'purple');DELIMITER //CREATE or REPLACE PROCEDURE p(tbl TEXT) ASDECLAREBEGINFOR x in COLLECT(CONCAT('SELECT id, name FROM ' , tbl), QUERY(id INT, name TEXT)) LOOPINSERT INTO output_log VALUES(CONCAT('[', x.id, ', ', x.name, ']'));END LOOP;END //DELIMITER ;CALL p('t2');SELECT * FROM output_log ORDER BY msg;
+-------------+
| msg |
+-------------+
| [1, orange] |
| [2, blue] |
| [3, purple] |
+-------------+
Related Topics
-
CREATE PROCEDURE: The
CREATE PROCEDURE
command creates a stored procedure. -
QUERY: A data type representing a
SELECT
statement. -
TO_
QUERY: Converts a SQL string to a query type value.
Last modified: April 4, 2023