CREATE AGGREGATE
On this page
Creates a user-defined aggregate function (UDAF).
Syntax
CREATE [OR REPLACE] AGGREGATE function_name ( [parameter_list] )RETURNS { data_type [data_type_modifier] }WITH STATE data_typeINITIALIZE WITH udf_function_nameITERATE WITH udf_function_nameMERGE WITH udf_function_nameTERMINATE WITH udf_function_nameparameter_list:data_type [data_type_modifier [, ...] ] [, ...]data_type_modifier:DEFAULT default_value | NOT NULL | NULL | COLLATE collation_name
Arguments
OR REPLACE
If specified, replaces a UDAF if one already exists with the same name.
function_
The name of the function.SUM()
.
You can also specify database_
and function_
together by replacing function_
with database_
instead of specifying the database in USING database_
.
CREATE AGGREGATE db.some_func(int)...
Function names are not case-sensitive.
WITH STATE
The STATE
type of a UDAF may be a scalar type, ARRAY
type, or a RECORD
type.
parameter_
Input parameters are optional.,
).
UDAFs only allow scalar data types as input parameters.
The following example shows how to declare a single input parameter:
CREATE AGGREGATE my_sum(BIGINT)...
The following example demonstrates how to declare more than one input parameters that also specify a data type modifier:
CREATE AGGREGATE multi_param_example(INT, VARCHAR(255) NOT NULL COLLATE utf8_bin, DECIMAL(19,4))...
udf_
The name of each UDF function to execute for the INITIALIZE WITH
, ITERATE WITH
, MERGE WITH
, and TERMINATE WITH
clauses.INITIALIZE
function takes in no arguments, and it returns a STATE
data type.ITERATE
function takes in a STATE
data type and the input parameter data type, and it returns a STATE
data type.n
parameters, the ITERATE
function will take in n+1
arguments, with the first argument being the STATE
type.MERGE
function takes in two STATE
data types, and it returns a STATE
data type.TERMINATE
function takes in a STATE
data type, and it returns the type specified in the RETURNS
clause.
MySQL Client Delimiters
When creating a UDF using a MySQL-compatible client connected to SingleStore, you must change the client delimiter to ensure that the function definition is correctly passed to the server and then set it back to a semicolon after the alternate delimiter is no longer needed.
Security and Permissions
The invoker of a UDAF must have EXECUTE
permissions on the UDAF.EXECUTE
permissions on each of the four UDFs that the UDAF uses.
Remarks
-
This command causes implicit commits.
Refer to COMMIT for more information.
Examples
Create UDAF
The following example creates a new UDAF named avg_
, which uses a RECORD
state type and has the same behavior as the builtin AVG
function.
Create UDF Dependencies
The avg_
example UDAF depends on the following UDFs:
DELIMITER //CREATE FUNCTION avg_init() RETURNS RECORD(s BIGINT, c BIGINT) ASBEGINRETURN ROW(0, 0);END //DELIMITER ;
DELIMITER //CREATE FUNCTION avg_iter(state RECORD(s BIGINT, c BIGINT), value BIGINT) RETURNS RECORD(s BIGINT, c BIGINT) ASBEGINRETURN ROW(state.s + value, state.c + 1);END //DELIMITER ;
DELIMITER //CREATE FUNCTION avg_merge(state1 RECORD(s BIGINT, c BIGINT), state2 RECORD(s BIGINT, c BIGINT)) RETURNS RECORD(s BIGINT, c BIGINT) ASBEGINRETURN row(state1.s + state2.s, state1.c + state2.c);END //DELIMITER ;
DELIMITER //CREATE FUNCTION avg_terminate(state RECORD(s BIGINT, c BIGINT)) RETURNS BIGINT ASBEGINRETURN state.s / state.c;END //DELIMITER ;
Create UDAF Example
Once the UDF dependencies have been created, you can create the UDAF.
CREATE AGGREGATE avg_udaf(BIGINT) RETURNS BIGINTWITH STATE RECORD(s BIGINT, c BIGINT)INITIALIZE WITH avg_initITERATE WITH avg_iterMERGE WITH avg_mergeTERMINATE WITH avg_terminate;
After the UDAF has been successfully created, execute the following commands to try it:
CREATE TABLE t (i BIGINT);INSERT INTO t VALUES (1), (2), (3), (4), (5);SELECT avg_udaf(i) FROM t;
+-------------+
| avg_udaf(i) |
+-------------+
| 3 |
+-------------+
1 row in set
Last modified: January 10, 2024