Miscellaneous Utility Functions
- Capella Operational
- reference
Miscellaneous utility functions enable you to perform tasks beyond the usual evaluation and transformation of data. For example, there are functions to retrieve information about a document or item, perform base64 encoding and decoding, generate UUIDs, and control the flow of a query.
ABORT(expression)
Description
Generates an error.
The error message contains the text specified by the given expression.
This function is useful for flow control when creating inline user-defined functions. You can use conditional operators to check the parameters, and use this function to generate an error if something is wrong.
Return Value
The function does not return a return value.
If this function is executed in a query, it causes the query to halt with an error code 5011.
The error message contains the text specified by the given expression.
When this function is executed by a user-defined function, it causes the query to halt with an error code 10109.
The error message shows the name of the user-defined function and contains the text specified by the given expression.
Examples
SELECT ABORT("Something went wrong");
[
{
"code": 5011,
"msg": "Abort: \"Something went wrong\". - cause: \"Something went wrong\""
}
]
CREATE OR REPLACE FUNCTION rstr(vString, vLen) LANGUAGE INLINE AS
CASE
WHEN NOT IS_STRING(vString)
THEN ABORT("Search string is not a string")
WHEN NOT IS_NUMBER(vLen)
THEN ABORT("Substring length is not a number")
WHEN vLen > LENGTH(vString)
THEN ABORT("Substring longer than search string")
ELSE SUBSTR(vString, LENGTH(vString) - vLen, vLen)
END;
EXECUTE FUNCTION rstr(100, 4);
[
{
"code": 10109,
"msg": "Error executing function rstr : \"Search string is not a string\" - cause: \"Search string is not a string\""
}
]
EXECUTE FUNCTION rstr("Couchbase", "foo");
[
{
"code": 10109,
"msg": "Error executing function rstr : \"Substring length is not a number\" - cause: \"Substring length is not a number\""
}
]
EXECUTE FUNCTION rstr("Couchbase", 10);
[
{
"code": 10109,
"msg": "Error executing function rstr : \"Substring longer than search string\" - cause: \"Substring longer than search string\""
}
]
EXECUTE FUNCTION rstr("Couchbase", 4);
[
"base"
]
BASE64(expression)
Alias: BASE64_ENCODE()
Description
Returns the base64 encoding of the given expression.
Return Value
A string representing the base64 encoding of the input expression.
If the input expression is missing, the return value is also missing.
Example
SELECT BASE64([1, 2, 3, 4]) AS `array`,
BASE64(false) AS `boolean`,
BASE64(missing) AS `missing`,
BASE64(null) AS `null`,
BASE64(1234) AS `number`,
BASE64( {"a": 1, "b": 2, "c": [1, 2, 3]} ) AS `object`,
BASE64("Couchbase") AS `string`;
[
{
"array": "WzEsMiwzLDRd",
"boolean": "ZmFsc2U=",
"null": "bnVsbA==",
"number": "MTIzNA==",
"object": "eyJhIjoxLCJiIjoyLCJjIjpbMSwyLDNdfQ==",
"string": "IkNvdWNoYmFzZSI="
}
]
BASE64_ENCODE(expression)
Alias of BASE64().
BASE64_DECODE(expression)
Description
Reverses the encoding done by the BASE64() or BASE64_ENCODE() functions.
Return Value
The decoded value of the input expression.
If the input expression is missing, the return value is also missing.
Example
SELECT BASE64_DECODE("WzEsMiwzLDRd") AS `array`,
BASE64_DECODE("ZmFsc2U=") AS `boolean`,
BASE64_DECODE(missing) AS `missing`,
BASE64_DECODE("bnVsbA==") AS `null`,
BASE64_DECODE("MTIzNA==") AS `number`,
BASE64_DECODE("eyJhIjoxLCJiIjoyLCJjIjpbMSwyLDNdfQ==") AS `object`,
BASE64_DECODE("IkNvdWNoYmFzZSI=") AS `string`;
[
{
"array": [
1,
2,
3,
4
],
"boolean": false,
"null": null,
"number": 1234,
"object": {
"a": 1,
"b": 2,
"c": [
1,
2,
3
]
},
"string": "Couchbase"
}
]
EVALUATE(statement [ ,params ])
Couchbase Server 8.0
Description
This function enables you to execute a SQL++ statement provided as a string and returns the result as an array. It can be used as a part of larger query or request, or wherever arrays are permitted within a statement.
The function evaluates the statement dynamically using the same permissions as the invoking statement.
The statement must be read-only. If it tries to modify data (like with UPDATE or INSERT), the function fails with error 5010, "not a readonly request”.
| The results are materialized in memory, so large result sets may require a lot of memory. To limit memory usage, you can use quotas (the evaluated statement operates within the invoking statement’s quota). |
Arguments
- statement
-
A string containing the statement to evaluate.
- params
-
Can be one of the following:
-
An object containing named parameters.
-
An array containing positional parameters.
-
Examples
SELECT EVALUATE("SELECT $named_param AS example",
{"named_param":"This is the named parameter's value"})
eval_result;
[
{
"eval_result": [
{
"example": "This is the named parameter's value"
}
]
}
]
SELECT `Flavor` FROM EVALUATE("INFER `travel-sample`")[0] inf;
[
{
"Flavor": "`type` = \"airport\""
},
{
"Flavor": "`stops` = 0, `type` = \"route\""
},
{
"Flavor": "`type` = \"landmark\""
},
{
"Flavor": "`type` = \"hotel\""
},
{
"Flavor": "`type` = \"airline\""
}
]
FINDERR(expression)
Couchbase Server 7.6.5
Arguments
- expression
-
One of the following:
-
A number representing an error code. In this case, the function returns the full details of the error matching the error code.
-
A string. In this case, the function searches for the target string in all of the error message fields except for
user_error, and returns the full details of any errors that match the string. -
A regular expression. In this case, the function searches for the regular expression in all of the error message fields except for
user_error, and returns the full details of any errors that match the pattern.
-
Return Value
The return value is an array of one or more objects, each of which contains the details of an error that matches the find expression.
For each error, the function returns the following fields.
| Name | Description | Schema |
|---|---|---|
applies_to |
One of the following:
|
enum (cbq-shell, Server) |
code |
A number representing the error. |
Integer |
description |
Message describing why the error occurred. |
String |
reason |
List of possible causes of the error. |
String array |
user_action |
List of possible steps a user can take to mitigate the error. |
String array |
user_error |
One of the following:
|
enum (Yes, No, Maybe) |
The error details also include a symbol field, which contains a representation string for the error.
This field is for internal use only, and is not shown in the results.
However, the FINDERR function does search this field when the find expression is a string or a regular expression.
|
Examples
SELECT FINDERR(5011);
[
{
"$1": [
{
"applies_to": "Server",
"code": 5011,
"description": "Abort: «reason»",
"reason": [
[
"The SQL++ abort() function was called in the statement.",
"e.g. SELECT abort('An example cause')"
]
],
"user_error": "Yes"
}
]
}
]
SELECT FINDERR("A semantic error is present in the statement.");
[
{
"$1": [
{
"applies_to": "Server",
"code": 3100,
"description": "A semantic error is present in the statement.",
"reason": [
"The statement includes portions that violate semantic constraints."
],
"user_action": [
"The cause will contain more detail on the violation; revise the statement and re-submit."
],
"user_error": "Yes"
}
]
}
]
SELECT FINDERR("semantic");
[
{
"$1": [
{
"applies_to": "Server",
"code": 3100,
"description": "A semantic error is present in the statement.",
"reason": [
"The statement includes portions that violate semantic constraints."
],
"user_action": [
"The cause will contain more detail on the violation; revise the statement and re-submit."
],
"user_error": "Yes"
},
{
"applies_to": "Server",
"code": 3220,
"description": "«name» window function «clause» «reason»",
"reason": [
"A violation of the window function semantic restrictions was present in the statement."
],
"user_action": [
"Revise the statement to remove the violation."
],
"user_error": "Yes"
},
{
"applies_to": "Server",
"code": 3300,
"description": "recursive_with semantics: «cause»",
"reason": [
"The statement specifies restricted syntax in a recursive common table expression definition."
],
"user_action": [
"Revise the statement removing the restricted syntax."
],
"user_error": "Yes"
}
]
}
]
SELECT FINDERR("[IU][NP]SERT");
[
{
"$1": [
{
"applies_to": "Server",
"code": 3150,
"description": "MERGE with ON KEY clause cannot have document key specification in INSERT action.",
"reason": [
[
"A lookup merge statement specified a document key.",
"e.g. MERGE INTO default USING [{},{}] AS source ON KEY 'aaa' WHEN NOT MATCHED THEN INSERT ('key',{})"
]
],
"user_action": [
"Refer to the documentation for lookup merge statements."
],
"user_error": "Yes"
},
// ...
{
"applies_to": "Server",
"code": 5072,
"description": "No UPSERT key for «value»",
"user_action": [
"Contact support."
]
},
// ...
{
"applies_to": "Server",
"code": 15005,
"description": "No keys to insert «details»"
}
]
}
]
FLATTEN_KEYS(expr1 [ modifiers ], expr2 [ modifiers ], …)
Description
This function can only be used when defining an index key for an array index.
If you need to index multiple fields within an array, this function enables you to flatten the specified expressions, and index them as if they were separate index keys. All subsequent index keys are accordingly moved to the right. Queries will be sargable and will generate spans.
Arguments
- expr1, expr2, …
-
[At least 1 and at most 32 argument-values are required] Each argument is an expression over a field within an array, which constitutes an array index key.
- modifiers
-
[Optional] Arguments can be modified with
ASCorDESCto specify the sort order of the index key. If this modifier is omitted, the default sort order isASC.The first argument may be also modified with
IGNORE MISSING. This modifier may only be used when the function is being used in the definition of the leading index key. If this modifier is present, documents which do not contain the specified field are indexed anyway. If this modifier is omitted, documents which do not contain the specified field are not indexed.When the
IGNORE MISSINGmodifier and theASCorDESCmodifier are used together, the order of the modifiers does not matter.
Note that FLATTEN_KEYS() cannot be used recursively.
Examples
For examples, refer to Array Indexing Examples.
FORMALIZE(statement [ ,query_context ])
Description
Fully expands all references within a query, using the specified query context.
This function has a synonym FORMALISE().
Arguments
- statement
-
A string containing the statement to formalize.
- query_context
-
[ Optional ] A string query context value for the function to use when formalizing.
Examples
SELECT formalize("SELECT * FROM landmark WHERE country = 'United Kingdom'","default:`travel-sample`.inventory")
[
{
"$1": "select self.* from `default`:`travel-sample`.`inventory`.`landmark` where ((`landmark`.`country`) = \"United Kingdom\")"
}
]
SELECT statement,
NVL(queryContext,"") AS queryContext,
formalize(statement, queryContext) AS formalized
FROM system:completed_requests;
[
{
"statement": "select * from `travel-sample`.inventory.landmark where country = 'United Kingdom' limit 1;",
"queryContext": "",
"formalized": "select self.* from `default`:`travel-sample`.`inventory`.`landmark` where ((`landmark`.`country`) = \"United Kingdom\") limit 1"
},
{
"statement": "select * from landmark where country = 'United Kingdom' limit 1;",
"queryContext": "`travel-sample`.inventory",
"formalized": "select self.* from `default`:`travel-sample`.`inventory`.`landmark` where ((`landmark`.`country`) = \"United Kingdom\") limit 1"
},
// ...
]
HASHBYTES(input, [ options ])
Couchbase Server 8.0
Description
This function returns a binary hash value for a given input using a specified hashing algorithm. By using this function, you can verify or compare data quickly, or protect your data by masking its original form while still allowing verification or comparison.
Arguments
- input
-
A binary object or any SQL++ data type. The JSON marshalled value of the data is used as the input.
- options
-
[Optional] An object that specifies the hashing algorithm and other options for the function. If omitted, the default hashing algorithm is
sha256.
Options
| Name | Description | Schema |
|---|---|---|
algorithm |
Specifies the hashing algorithm to be used. Supported algorithms are: |
String |
polynomial |
The polynomial to use.
This only applies if the algorithm is
Default: |
String or integer |
Return Value
A binary hash value. The size or length of the value depends on the algorithm you choose.
Examples
sha256 algorithmSELECT HASHBYTES('Hello World', {"algorithm":"sha256"});
[
{
"$1": "a591a6d40bf420404a011733cfb7b190d62c65bf0bcda32b57b277d9ad9f146e"
}
]
crc32 algorithmSELECT HASHBYTES("hello world", {"algorithm":"crc32", "polynomial":"koopman"});
[
{
"$1": "df373d3c"
}
]
LEN(expression)
Return Value
The return value is usually a number, depending on the datatype of the input expression.
| Input Expression | Return Value |
|---|---|
String |
The number of code points in the string — equivalent to LENGTH(). |
Object |
The field count — equivalent to OBJECT_LENGTH(). |
Array |
The number of elements — equivalent to ARRAY_LENGTH(). |
Binary |
The size of the binary object. |
Boolean |
|
Number |
The number of characters in the number’s text representation. |
MISSING |
|
NULL |
|
For any item not listed above, the return value is null.
Example
SELECT LEN([1, 2, 3, 4]) AS `array`,
LEN(false) AS `boolean`,
LEN(missing) AS `missing`,
LEN(null) AS `null`,
LEN(1234) AS `number`,
LEN( {"a": 1, "b": 2, "c": [1, 2, 3]} ) AS `object`,
LEN("Couchbase") AS `string`;
[
{
"array": 4,
"boolean": 1,
"null": null,
"number": 4,
"object": 3,
"string": 9
}
]
META( [ keyspace_expr ] ) [ .property ]
Description
This function returns the metadata for the document or keyspace specified by keyspace_expr.
The metadata is returned as a JSON object.
To return a single property from the metadata, you must use a nested expression containing the META() function and the required property, for example META().id.
The supported metadata properties are described below.
You can use the META() function with a property to index metadata information.
Only certain metadata properties are indexable; these are indicated in the description below.
You can also use the META() function with a property in the predicate of an ANSI JOIN Clause.
If your cluster is running Couchbase Server version 7.6.2 and later, use the META() function with the SEARCH() function when you want to return XATTRs data through the Search Service and do not have a suitable Search index for your query.
Arguments
- keyspace_expr
-
[Optional. Default is current keyspace.]
String or an expression that results in a keyspace or a document. This argument is not required when creating an index, since the
META()function implicitly uses the keyspace being indexed. - property
-
[Optional] The name of a single metadata property. The property name must be separated from the
META()function by a dot (.) and may be one of the following:- cas
-
Value representing the current state of an item which changes every time the item is modified. For details, refer to Concurrent Document Mutations.
This property is indexable.
- expiration
-
Value representing a document’s expiration date. A value of 0 (zero) means no expiration date. For details, refer to KV Operations.
This property is indexable.
- flags
-
Value set by the SDKs for non-JSON documents. For details, refer to Non-JSON Documents.
This property is not indexable. If you attempt to build an index on this property, an error is returned.
- id
-
Value representing a document’s unique ID number.
This property is indexable.
- type
-
Value for the type of document; currently only
jsonis supported.This property is not indexable. If you attempt to build an index on this property, an error is returned.
- xattrs
-
Value representing extended attributes (XATTRs) of a document.
To access XATTRs, use the syntax
META().xattrs.<attribute>[.<path>], where:-
<attribute>is a top-level attribute name or key of the XATTR object. -
<path>is an optional subpath within that attribute.
While you can create an index on a specific extended attribute like
META().xattrs.attr1, you cannot create an index on the entireMETA().xattrsobject itself.Attempting to select the entire
META().xattrsobject will return an empty result.Starting with Couchbase Server 8.0, you can include up to 15 XATTRs per query. -
Return Value
The bare function returns a JSON object containing the specified document’s metadata. When the function is used with a property as part of a nested expression, the expression returns the JSON value of the property.
Examples
To try the examples in this section, set the query context to the inventory scope in the travel sample dataset.
For more information, see Query Context.
SELECT META() AS metadata
FROM airline
LIMIT 3;
[
{
"metadata": {
"cas": 1583859008179798016,
"expiration": 0,
"flags": 33554432,
"id": "airline_10",
"type": "json"
}
},
{
"metadata": {
"cas": 1583859008180846592,
"expiration": 0,
"flags": 33554432,
"id": "airline_10123",
"type": "json"
}
},
{
"metadata": {
"cas": 1583859008181895168,
"expiration": 0,
"flags": 33554432,
"id": "airline_10226",
"type": "json"
}
}
]
SELECT META().id AS id
FROM airline
LIMIT 3;
[
{
"id": "airline_10"
},
{
"id": "airline_10123"
},
{
"id": "airline_10226"
}
]
SELECT META(route).id AS id (1)
FROM route
JOIN airport
ON route.sourceairport = airport.faa
WHERE airport.city = "Paris"
LIMIT 3;
| 1 | You must specify a keyspace for the META() function because there is more than one FROM term. |
[
{
"id": "route_10136"
},
{
"id": "route_10137"
},
{
"id": "route_10138"
}
]
For examples showing how to index metadata information, refer to Indexing Meta Info.
For examples showing how to use metadata information in the predicate of an ANSI JOIN clause, refer to JOIN Clause.
NODE_UUID(expression)
Arguments
- expression
-
A string, or an expression resolving to a string, representing a node name. To get the UUID of the node on which the query is running, use the empty string
"".
Return Value
A string representing the node UUID.
If the input expression is not a string, the return value is null.
If the input expression is missing, the return value is also missing.
Example
SELECT NODE_UUID("") AS from_empty_string,
NODE_UUID("<redacted>-node-001.<redacted>:8091") AS from_node_name,
NODE_UUID(NODE_NAME()) AS from_node_name_function;
[
{
"from_empty_string": "<redacted UUID>",
"from_node_name": "<redacted UUID>",
"from_node_name_function": "<redacted UUID>"
}
]
PAIRS(obj)
Description
This function generates an array of arrays of [field_name, value] pairs of all possible fields in the given JSON object obj.
| Nested sub-object fields are explored recursively. |
Return Value
Array of [field_name, value] arrays for each field in the input object obj.
-
If
objhas nested objects, then fields of such nested sub-objects are also explored and corresponding inner-array elements are produced. -
If
objis an array, then each element of the array is explored and corresponding inner-array elements are produced. -
If
objis a primitive data type of integer or string, then it returns NULL, as they don’t have a name. -
If
objis an array of primitive data types, then it returns an empty array[]. -
If
objis an array of objects, then it returns an array of objects.
|
If you wrap an array of primitive data types in an object constructor, it’s treated as an object and returns an array; without the object constructor, it’s treated as an array of primitive data types and returns
|
Examples
To try the examples in this section, set the query context to the inventory scope in the travel sample dataset.
For more information, see Query Context.
SELECT t AS orig_t,
PAIRS(t) AS pairs_t
FROM airport t
LIMIT 1;
[
{
"orig_t": {
"airportname": "Calais Dunkerque",
"city": "Calais",
"country": "France",
"faa": "CQF",
"geo": {
"alt": 12,
"lat": 50.962097,
"lon": 1.954764
},
"icao": "LFAC",
"id": 1254,
"type": "airport",
"tz": "Europe/Paris"
},
"pairs_t": [
[
"id",
1254
],
[
"city",
"Calais"
],
[
"faa",
"CQF"
],
[
"geo",
{
"alt": 12,
"lat": 50.962097,
"lon": 1.954764
}
],
[
"lon",
1.954764
],
[
"alt",
12
],
[
"lat",
50.962097
],
[
"type",
"airport"
],
[
"tz",
"Europe/Paris"
],
[
"airportname",
"Calais Dunkerque"
],
[
"country",
"France"
],
[
"icao",
"LFAC"
]
]
}
]
SELECT public_likes AS orig_t,
PAIRS(public_likes) AS pairs_array_t,
PAIRS({public_likes}) AS pairs_obj_t
FROM hotel
LIMIT 1;
[
{
"orig_t": [
"Julius Tromp I",
"Corrine Hilll",
"Jaeden McKenzie",
"Vallie Ryan",
"Brian Kilback",
"Lilian McLaughlin",
"Ms. Moses Feeney",
"Elnora Trantow"
],
"pairs_array_t": [],
"pairs_obj_t": [
[
"public_likes",
[
"Julius Tromp I",
"Corrine Hilll",
"Jaeden McKenzie",
"Vallie Ryan",
"Brian Kilback",
"Lilian McLaughlin",
"Ms. Moses Feeney",
"Elnora Trantow"
]
],
[
"public_likes",
"Julius Tromp I"
],
[
"public_likes",
"Corrine Hilll"
],
[
"public_likes",
"Jaeden McKenzie"
],
[
"public_likes",
"Vallie Ryan"
],
[
"public_likes",
"Brian Kilback"
],
[
"public_likes",
"Lilian McLaughlin"
],
[
"public_likes",
"Ms. Moses Feeney"
],
[
"public_likes",
"Elnora Trantow"
]
]
}
]
SELECT country AS orig_t,
PAIRS(country) AS pairs_t
FROM airport
LIMIT 1;
[
{
"orig_t": "France",
"pairs_t": null
}
]
SELECT PAIRS("N1QL") AS constant_string,
PAIRS(4) AS constant_int,
PAIRS([1,2,3]) AS constant_int_array,
PAIRS({"name" : 3}) AS object_constant_int,
PAIRS({"name" : [1,2,3]}) AS object_constant_int_array;
[
{
"constant_int": null,
"constant_int_array": [],
"constant_string": null,
"object_constant_int": [
[
"name",
3
]
],
"object_constant_int_array": [
[
"name",
[
1,
2,
3
]
],
[
"name",
1
],
[
"name",
2
],
[
"name",
3
]
]
}
]
SELECT reviews[*].ratings,
PAIRS({reviews[*].ratings}) AS pairs_t
FROM hotel
LIMIT 1;
[
{
"pairs_t": [
[
"ratings",
[
{
"Cleanliness": 5,
"Location": 4,
"Overall": 4,
"Rooms": 3,
"Service": 5,
"Value": 4
},
{
"Business service (e.g., internet access)": 4,
"Check in / front desk": 4,
"Cleanliness": 4,
"Location": 4,
"Overall": 4,
"Rooms": 3,
"Service": 3,
"Value": 5
}
]
],
[
"ratings",
{
"Cleanliness": 5,
"Location": 4,
"Overall": 4,
"Rooms": 3,
"Service": 5,
"Value": 4
}
],
[
"ratings",
{
"Business service (e.g., internet access)": 4,
"Check in / front desk": 4,
"Cleanliness": 4,
"Location": 4,
"Overall": 4,
"Rooms": 3,
"Service": 3,
"Value": 5
}
],
[
"Cleanliness",
5
],
[
"Location",
4
],
[
"Overall",
4
],
[
"Rooms",
3
],
[
"Service",
5
],
[
"Value",
4
],
[
"Cleanliness",
4
],
[
"Location",
4
],
[
"Rooms",
3
],
[
"Value",
5
],
[
"Business service (e.g., internet access)",
4
],
[
"Check in / front desk",
4
],
[
"Overall",
4
],
[
"Service",
3
]
],
"ratings": [
{
"Cleanliness": 5,
"Location": 4,
"Overall": 4,
"Rooms": 3,
"Service": 5,
"Value": 4
},
{
"Business service (e.g., internet access)": 4,
"Check in / front desk": 4,
"Cleanliness": 4,
"Location": 4,
"Overall": 4,
"Rooms": 3,
"Service": 3,
"Value": 5
}
]
}
]
UNNEST_POS(expr)
You can use the UNNEST_POS() function with the UNNEST Clause to return the position of each element in an unnested array.
This function has a synonym UNNEST_POSITION().
Description
The UNNEST_POS function takes an unnested array and returns the position value of each element in the array.
Arguments
- expr
-
[Required] The alias of the unnested array from an UNNEST Clause.
Return Values
The UNNEST_POS function returns the position of each element in the unnested array, expr, as an integer. It returns each position value as a separate row in JSON format. The first element in the array is at position 0.
In all other cases, the UNNEST_POS function returns NULL or MISSING.
Example
In the following example, the UNNEST_POS function takes the result of an UNNEST Clause on a given array, a1. The UNNEST function returns the position of each element in the unnested a1 array , u, as the upos value.
SELECT UNNEST_POS(u) AS upos, u FROM [{"a1":[10,9,4]}] AS d UNNEST d.a1 AS u;
[
{
"u": 10,
"upos": 0
},
{
"u": 9,
"upos": 1
},
{
"u": 4,
"upos": 2
}
]
UNNEST_POSITION(expr)
Synonym of UNNEST_POS().
UUID()
Description
Generates a universally unique identifier (UUID) according to RFC 4122.