The CREATE FUNCTION
statement enables you to create a user-defined function.
Purpose
There are two types of user-defined function in SQL++ for Query:
-
Inline functions are defined using SQL++ expressions. They enable you to name and reuse complex or repetitive expressions, including subqueries, in order to simplify your queries.
-
External functions are defined using an external language. They enable you to create functions that may be difficult or impossible to define using built-in SQL++ expressions. The only supported language is JavaScript.
External functions in SQL++ support most of the language constructs available in ECMAScript. For more information about the restrictions and extensions that come with the Couchbase implementation, see JavaScript Functions for Query Reference.
Global Functions and Scoped Functions
You can create user-defined functions at two different levels of the SQL++ logical hierarchy.
-
A global function is created within a namespace, at the same level as the buckets within the namespace. When you call a global function, any partial keyspace references within the function definition are resolved against the function’s namespace, regardless of the current query context.
For example, when you call a global function
default:global()
which contains the keyspace reference`travel-sample`
, the keyspace reference is always resolved within the context of the function to thedefault:`travel-sample`
bucket. -
A scoped function is created within a scope, at the same level as the collections within the scope. When you call a scoped function, any partial keyspace references within the function definition are resolved against the function’s scope, regardless of the current query context.
For example, when you call a scoped function
default:`travel-sample`.inventory.scope()
which contains the keyspace referenceroute
, the keyspace reference is always resolved within the context of the function todefault:`travel-sample`.inventory.route
.
When you create a user-defined function, the current query context determines whether it is created as a global function or a scoped function. If you want to create a user-defined function outside of the current query context, you must include the full path to the function when you specify the function name.
Similarly, when you call a user-defined function, the current query context determines the path to the function. If you want to call a user-defined function outside of the current query context, you must include the full path to the function when you specify the function name.
Finally, it is important to note that a global function is not the same as a scoped function stored in the default scope in a bucket.
External Libraries
You can store JavaScript functions in external libraries. This enables you to share external function code for use in more than one SQL++ user-defined function. A library can contain one or more JavaScript functions.
You must create the external library and the external function code using the Query Workbench or the SQL++ Functions REST API.
External libraries, like SQL++ user-defined functions, may be scoped or global. This enables you to keep the code for external functions separate where required.
Code which is stored in a scoped library is private to users of that scope, and is not visible or available to users of another scope. Code which is stored in a global library is available to users of all scopes.
A global library may have the same name as a scoped library, and scoped libraries may have the same name as each other.
For example, you may have a global math
library, and a math
library in each scope.
SQL++ Managed User-Defined Functions
(Introduced in Couchbase Server 7.6)
In Couchbase Server 7.6 and later, you can create the code for an external function and the corresponding SQL++ user-defined function in a single operation. This means that you don’t have to specify an external library and create the code for the external function, before creating the SQL++ user-defined function.
With a SQL++ managed user-defined function, the external function code is stored inline, along with the SQL++ user-defined function. You cannot share this external function code with other user-defined functions, or access it from any external libraries.
Prerequisites
To manage … | You must have … |
---|---|
Global inline functions |
Manage Global Functions role. |
Scoped inline functions |
Manage Scope Functions role, with permissions on the specified bucket and scope. |
Global external functions |
Manage Global External Functions role. |
Scoped external functions |
Manage Scope External Functions role, with permissions on the specified bucket and scope. |
Users with the Manage Scope External Functions role also have read-only access to any global external library.
To execute … | You must have … |
---|---|
Global inline functions |
Execute Global Functions role. |
Scoped inline functions |
Execute Scope Functions role, with permissions on the specified bucket and scope. |
Global external functions |
Execute Global External Functions role. |
Scoped external functions |
Execute Scope External Functions role, with permissions on the specified bucket and scope. |
For more details about user roles, see Authorization.
Syntax
The CREATE FUNCTION
statement takes a different syntax depending on the type of function you are creating.
Refer to Inline Functions or External Functions below.
create-function ::= create-function-inline | create-function-external
Inline Functions
There are two alternative syntaxes for defining an inline function: a syntax with braces {}
and a syntax using the LANGUAGE
keyword.
The two syntaxes are synonymous.
create-function-inline ::= 'CREATE' ( 'OR' 'REPLACE' )? 'FUNCTION' function '(' params? ')'
( 'IF' 'NOT' 'EXISTS' )?
( '{' body '}' | 'LANGUAGE' 'INLINE' 'AS' body )
function | |
params | |
body |
OR REPLACE / IF NOT EXISTS
The optional OR REPLACE
clause enables you to redefine a user-defined function if it already exists, whereas the optional IF NOT EXISTS
clause enables the statement to complete successfully without replacing the function.
When a function with the same name already exists within the same context: [1]
-
If the
OR REPLACE
clause is present, the existing function is replaced. -
If the
IF NOT EXISTS
clause is present, the statement does nothing and completes without error. -
If neither of these two clauses is present, an error is generated.
These clauses are exclusive.
If the statement contains both the OR REPLACE clause and the IF NOT EXISTS clause, an error is generated.
|
Function Name
function ::= ( namespace ':' ( bucket '.' scope '.' )? )? identifier
The function name specifies the name of the function to create.
It is recommended to use an unqualified identifier for the function name, such as func1
or `func-1`
.
In this case, the function is created as a global function or a scoped function, depending on the current query context.
To create a global function in a particular namespace, the function name must be a qualified identifier with a namespace, such as default:func1
.
Similarly, to create a scoped function in a particular scope, the function name must be a qualified identifier with the full path to a scope, such as default:`travel-sample`.inventory.func1
.
If the function name is an unqualified identifier, it may not be the same as a reserved keyword. A function name with a specified namespace or scope may have the same name as a reserved keyword.
Function Parameters
params ::= identifier ( "," identifier )* | "..."
[Optional] The function parameter list specifies parameters for the function.
If you specify named parameters for the function, then you must call the function with exactly the same number of arguments at execution time.
If you specify no parameters, then you must call the function with no arguments.
To create a variadic function, that is, a function which you can call with any number of arguments or none, specify ...
as the only parameter.
Function Body
The function body defines the function.
You can use any valid SQL++ expression.
If you specified named parameters for the function, you can use these in the expression to represent arguments passed to the function at execution time.
If you specified that the function is variadic, any arguments passed to the function at execution time are held in an array named args
.
|
External Functions
There are two alternative syntaxes for defining an external function: one where the function code is stored in an external library, and one for creating a SQL++ managed user-defined function.
create-function-external ::= 'CREATE' ( 'OR' 'REPLACE' )? 'FUNCTION' function '(' params? ')'
( 'IF' 'NOT' 'EXISTS' )?
'LANGUAGE' 'JAVASCRIPT' 'AS' ( obj 'AT' library | javascript )
function | |
params | |
obj | |
library | |
javascript |
OR REPLACE / IF NOT EXISTS
The optional OR REPLACE
clause enables you to redefine a user-defined function if it already exists, whereas the optional IF NOT EXISTS
clause enables the statement to complete successfully without replacing the function.
When a function with the same name already exists within the same context: [1]
-
If the
OR REPLACE
clause is present, the existing function is replaced. -
If the
IF NOT EXISTS
clause is present, the statement does nothing and completes without error. -
If neither of these two clauses is present, an error is generated.
These clauses are exclusive.
If the statement contains both the OR REPLACE clause and the IF NOT EXISTS clause, an error is generated.
|
Function Name
function ::= ( namespace ':' ( bucket '.' scope '.' )? )? identifier
The function name specifies the name of the function to create.
It is recommended to use an unqualified identifier for the function name, such as func1
or `func-1`
.
In this case, the function is created as a global function or a scoped function, depending on the current query context.
To create a global function in a particular namespace, the function name must be a qualified identifier with a namespace, such as default:func1
.
Similarly, to create a scoped function in a particular scope, the function name must be a qualified identifier with the full path to a scope, such as default:`travel-sample`.inventory.func1
.
If the function name is an unqualified identifier, it may not be the same as a reserved keyword. A function name with a specified namespace or scope may have the same name as a reserved keyword.
Function Parameters
params ::= identifier ( "," identifier )* | "..."
[Optional] The function parameter list specifies parameters for the function.
If you specify named parameters for the function, then you must call the function with exactly the same number of arguments at execution time.
If you specify no parameters, then you must call the function with no arguments.
To create a variadic function, that is, a function which you can call with any number of arguments or none, specify ...
as the only parameter.
External Object
[Optional] Use this parameter where the function code is stored in an external library.
The name of the JavaScript function that you want to use for the user-defined function. This parameter is a string and must be wrapped in quotes.
External Library
[Optional] Use this parameter where the function code is stored in an external library.
The name of the JavaScript library that contains the JavaScript function you want to use. This parameter is a string and must be wrapped in quotes.
The name of a scoped external library must include the bucket name, the scope name, and the library name, separated by slashes.
For example, to refer to a scoped library called my-library
located in the inventory
scope within the travel-sample
bucket, you would specify the library name as travel-sample/inventory/my-library
.
Function Body
[Optional] Use this parameter to create a SQL++ managed user-defined function.
The external JavaScript function code. This must contain a function with the same name and the same number of parameters as the SQL++ user-defined function. This parameter is a string and must be wrapped in quotes.
The JavaScript code can contain multiple function definitions, but these functions can only be referenced within the JavaScript code for this SQL++ user-defined function, and cannot be shared.
Examples
For simplicity, none of these examples implement any data validation or error checking. If necessary, you can use conditional operators to check the parameters of a user-defined function, and the ABORT() function to generate an error if something is wrong.
This statement creates a function called celsius
, which converts Fahrenheit to Celsius.
The function is variadic.
For purposes of illustration, this expression converts just the first argument supplied at execution time, which is stored in the first member in the args
array.
A more realistic variadic function would make use of all the supplied arguments.
CREATE FUNCTION celsius(...) LANGUAGE INLINE AS (args[0] - 32) * 5/9;
EXECUTE FUNCTION celsius(100);
[
37.77777777777778
]
This statement creates a function called fahrenheit
, which converts Celsius to Fahrenheit.
The function is variadic.
For purposes of illustration, this expression converts just the first argument supplied at execution time, which is stored in the first member in the args
array.
A more realistic variadic function would make use of all the supplied arguments.
CREATE FUNCTION fahrenheit(...) { (args[0] * 9/5) + 32 };
EXECUTE FUNCTION fahrenheit(100, "ignore this");
[
212
]
As the function is variadic, you can use any number of arguments when you call the function. Arguments which are not used by the function expression are ignored.
The following statement creates a function called lstr
, which returns the specified number of characters from the left of a string.
The expression expects two named arguments: vString
, which is the string to work with, and vLen
, which is the number of characters to return.
CREATE FUNCTION lstr(vString, vLen) LANGUAGE INLINE AS SUBSTR(vString, 0, vLen);
EXECUTE FUNCTION lstr("Couchbase", 5, "ignore this");
[
{
"code": 10104,
"msg": "Incorrect number of arguments supplied to function lstr - cause: lstr"
}
]
As the arguments were specified by the function definition, you must use the same number of arguments when you call the function. If you supply the wrong number of arguments, an error is generated.
The following statement creates a function called rstr
, which returns the specified number of characters from the right of a string.
The expression expects two named arguments: vString
, which is the string to work with, and vLen
, which is the number of characters to return.
CREATE FUNCTION rstr(vString, vLen) { SUBSTR(vString, LENGTH(vString) - vLen, vLen) };
EXECUTE FUNCTION rstr("Couchbase", 4);
[
"base"
]
The following statement creates a function called locations
, which selects name and address information from all documents with the specified activity in the landmark
keyspace.
CREATE FUNCTION locations(vActivity) { (
SELECT id, name, address, city
FROM landmark
WHERE activity = vActivity) };
EXECUTE FUNCTION locations("see");
[
[
{
"address": "Prince Arthur Road, ME4 4UG",
"city": "Gillingham",
"id": 10019,
"name": "Royal Engineers Museum"
},
{
"address": "84 rue Claude Monet",
"city": "Giverny",
"id": 10061,
"name": "Monet's House"
},
...
This statement creates a function which returns the mathematical constant φ. The function takes no arguments.
CREATE FUNCTION phi() { 2 * SIN(RADIANS(54)) };
EXECUTE FUNCTION phi();
[
1.618033988749895
]
The following statement redefines the function so that it calculates φ using a different method.
CREATE OR REPLACE FUNCTION phi() { (1 + SQRT(5)) / 2 };
EXECUTE FUNCTION phi();
[
1.618033988749895
]
The following statement creates external JavaScript function code and the corresponding SQL++ user-defined function in one operation.
CREATE FUNCTION add100(num) LANGUAGE JAVASCRIPT AS
"function add100(param1) {return param1+100;}";
EXECUTE FUNCTION add100(100);
[
200
]
The following command registers two JavaScript functions called encodeGeoHash
and calculateAdjacent
in a library called geohash-js
.
[2]
-
The function
encodeGeoHash
takes two arguments, a latitude and a longitude, and returns the 12-character geohash for the specified location. -
The function
calculateAdjacent
takes two arguments, a geohash and a direction —"top"
,"bottom"
,"left"
, or"right"
— and returns the geohash of the location next to the original geohash in the specified direction.
curl -v -X POST \
http://localhost:8093/evaluator/v1/libraries/geohash-js \
-u Administrator:password \
-H 'content-type: application/json' \
-d 'function encodeGeoHash(latitude, longitude) {
var BITS = [16, 8, 4, 2, 1];
var BASE32 = "0123456789bcdefghjkmnpqrstuvwxyz";
var is_even = 1;
var i = 0, mid;
var lat = []; var lon = [];
var bit = 0;
var ch = 0;
var precision = 12;
var geohash = "";
lat[0] = -90.0; lat[1] = 90.0;
lon[0] = -180.0; lon[1] = 180.0;
while (geohash.length < precision) {
if (is_even) {
mid = (lon[0] + lon[1]) / 2;
if (longitude > mid) {
ch |= BITS[bit];
lon[0] = mid;
} else
lon[1] = mid;
} else {
mid = (lat[0] + lat[1]) / 2;
if (latitude > mid) {
ch |= BITS[bit];
lat[0] = mid;
} else
lat[1] = mid;
}
is_even = !is_even;
if (bit < 4)
bit++;
else {
geohash += BASE32[ch];
bit = 0;
ch = 0;
}
}
return geohash;
}
function calculateAdjacent(srcHash, dir) {
var BITS = [16, 8, 4, 2, 1];
var BASE32 = "0123456789bcdefghjkmnpqrstuvwxyz";
var NEIGHBORS = { right : { even : "bc01fg45238967deuvhjyznpkmstqrwx" },
left : { even : "238967debc01fg45kmstqrwxuvhjyznp" },
top : { even : "p0r21436x8zb9dcf5h7kjnmqesgutwvy" },
bottom : { even : "14365h7k9dcfesgujnmqp0r2twvyx8zb" } };
var BORDERS = { right : { even : "bcfguvyz" },
left : { even : "0145hjnp" },
top : { even : "prxz" },
bottom : { even : "028b" } };
NEIGHBORS.bottom.odd = NEIGHBORS.left.even;
NEIGHBORS.top.odd = NEIGHBORS.right.even;
NEIGHBORS.left.odd = NEIGHBORS.bottom.even;
NEIGHBORS.right.odd = NEIGHBORS.top.even;
BORDERS.bottom.odd = BORDERS.left.even;
BORDERS.top.odd = BORDERS.right.even;
BORDERS.left.odd = BORDERS.bottom.even;
BORDERS.right.odd = BORDERS.top.even;
srcHash = srcHash.toLowerCase();
var lastChr = srcHash.charAt(srcHash.length - 1);
var type = (srcHash.length % 2) ? "odd" : "even";
var base = srcHash.substring(0, srcHash.length - 1);
if (BORDERS[dir][type].indexOf(lastChr) != -1)
base = calculateAdjacent(base, dir);
return base + BASE32[NEIGHBORS[dir][type].indexOf(lastChr)];
}'
The following statements create two functions:
-
A function called
geohash
, which calls the JavaScriptencodeGeoHash
function from thegeohash-js
library; -
A function called
adjacent
, which calls the JavaScriptcalculateAdjacent
function from thegeohash-js
library.
CREATE FUNCTION geohash(lat, lon)
LANGUAGE JAVASCRIPT AS "encodeGeoHash" AT "geohash-js";
CREATE FUNCTION adjacent(src, dir)
LANGUAGE JAVASCRIPT AS "calculateAdjacent" AT "geohash-js";
geohash
EXECUTE FUNCTION geohash(53.353744, -2.27495);
[
"gcqrs0z2jfdr"
]
To view the geohash on a map, go to http://geohash.org/gcqrs0z2jfdr and follow one of the links provided. At the specified latitude, the geohash represents an area of approximately 11 𐄂 19 millimeters.
adjacent
EXECUTE FUNCTION adjacent(geohash(53.353744, -2.27495), "top");
[
"gcqrs0z2jff2"
]
To view the geohash on a map, go to http://geohash.org/gcqrs0z2jff2 and follow one of the links provided. At this level of precision, the geohash should appear to be in almost exactly the same location as the previous one.
Related Links
-
To manage user-defined functions in the Query Workbench, see User-Defined Functions UI.
-
To manage external libraries and external functions, see Query Functions REST API.
-
To execute a user-defined function, see EXECUTE FUNCTION.
-
To see the execution plan for a user-defined function, see EXPLAIN FUNCTION.
-
To include a user-defined function in an expression, see User-Defined Functions.
-
To monitor user-defined functions, see Monitor Functions.
-
To drop a user-defined function, see DROP FUNCTION.