SQL++ Query Strings
Description — How to use SQL++ Query Strings to build effective queries with Couchbase Lite on Objective-C
Related Content — Predictive Queries | Live Queries | Indexing
The examples used in this topic are based on the Travel Sample app and data introduced in the Couchbase Mobile Workshop tutorial |
Introduction
Developers using Couchbase Lite for Objective-C can provide SQL++ query strings using the SQL++ Query API. This API uses query statements of the form shown in Example 2.
The structure and semantics of the query format are based on that of Couchbase Server’s SQL++ query language — see SQL++ Reference Guide and SQL++ Data Model.
Running
The database can create a query object with the SQL++ string. See Query Resultsets for how to work with result sets.
NSString *queryString = @"SELECT * FROM _ WHERE type = \"hotel\""; (1)
CBLQuery *query = [self.database createQuery:queryString error: &error];
CBLQueryResultSet *results = [query execute:&error];
We are accessing the current database using the shorthand notation _
— see the FROM clause for more on data source selection and Query Parameters for more on parameterized queries.
Query Format
The API uses query statements of the form shown in Example 2.
SELECT ____
FROM 'data-source'
WHERE ____,
JOIN ____
GROUP BY ____
ORDER BY ____
LIMIT ____
OFFSET ____
- Query Components
Component | Description |
---|---|
The document properties that will be returned in the result set |
|
The data source to be queried |
|
The criteria for joining multiple documents |
|
The query criteria |
|
The criteria used to unpack arrays within a document into individual rows |
|
The criteria used to group returned items in the result set |
|
The criteria used to order the items in the result set |
|
The maximum number of results to be returned |
|
The number of results to be skipped before starting to return results |
We recommend working through the SQL++ Tutorials to build your SQL++ skills. |
SELECT statement
Syntax
select = SELECT _ ( DISTINCT | ALL )? selectResult (1)
selectResults = selectResult ( _ ',' _ selectResult )* (2)
selectResult = expression ( _ (AS)? columnAlias )? (3)
columnAlias = IDENTIFIER
Arguments
1 | The select clause begins with the SELECT keyword.
|
2 | selectResults is a list of columns projected in the query result. Each column is an expression which could be a property expression or any expressions or functions. You can use the wildcard * to select all columns — see Select Wildcard |
3 | Use the optional AS argument to provides an alias name for a property. Each property can be aliased by putting the AS <alias name> after the column name. |
Select Wildcard
When using the SELECT *
option the column name (key) of the SQL++ string is one of:
-
The alias name if one was specified
-
The data source name (or its alias if provided) as specified in the
FROM
clause.
This behavior is inline with that of Couchbase Server SQL++ — see example in Table 1.
Query | Column Name |
---|---|
|
|
|
|
|
|
|
|
|
|
Example
SELECT * (1)
SELECT db.* AS data (2)
SELECT name fullName (3)
SELECT db.name fullName (4)
SELECT DISTINCT address.city (5)
1 | Use the * wildcard to select all properties |
2 | Select all properties from the db data source. Give the object an alias name of data |
3 | Select pair of properties |
4 | Select a specific property from the db data source. |
5 | Select the property item city from its parent property address . |
See: Query Resultsets for more on processing query results.
FROM
Purpose
Specifies the data source, or sources, and optionally applies an alias ( AS
).
It is mandatory.
Datasource
A datasource can be:
-
< database-name > : default collection
-
_ (underscore) : default collection
-
< scope-name >.< collection-name > : a collection in a scope
-
< collection-name > : a collection in the default scope
Arguments
1 | Here dataSource is the database name against which the query is to run or the <scope>.<collection>.
Use AS to give the database an alias you can use within the query.To use the current datasource without specifying a name, use _ as the datasource. |
2 | JOIN joinclause — use this optional argument to link datasources — see JOIN statement |
JOIN statement
Purpose
The JOIN clause enables you to select data from multiple data sources linked by criteria specified in the JOIN statement.
Currently only self-joins are supported. For example to combine airline details with route details, linked by the airline id — see Example 6.
Syntax
joinClause = ( join )*
join = joinOperator _ dataSource _ (constraint)? (1)
joinOperator = ( LEFT (OUTER)? | INNER | CROSS )? JOIN (2)
dataSource = databaseName ( ( AS | _ )? databaseAlias )?
constraint ( ON expression )? (3)
Arguments
1 | The join clause starts with a JOIN operator followed by the data source. |
2 | Five JOIN operators are supported: JOIN, LEFT JOIN, LEFT OUTER JOIN, INNER JOIN, and CROSS JOIN. Note: JOIN and INNER JOIN are the same, LEFT JOIN and LEFT OUTER JOIN are the same. |
3 | The join constraint starts with the ON keyword followed by the expression that defines the joining constraints. |
Example
SELECT db.prop1, other.prop2 FROM db JOIN db AS other ON db.key = other.key
SELECT db.prop1, other.prop2 FROM db LEFT JOIN db other ON db.key = other.key
SELECT * FROM route r JOIN airline a ON r.airlineid = meta(a).id WHERE a.country = "France"
This example JOINS the document of type route
with documents of type airline
using the document ID (id
) on the _airline document and airlineid
on the route document.
SELECT * FROM travel-sample r JOIN travel-sample a ON r.airlineid = a.meta.id WHERE a.country = "France"
Array UNNEST
Purpose
You can use UNNEST
in queries to unpack arrays within a document into individual rows.
This functionality makes it possible to join them with its parent object in the query.
UNNEST
is used within the FROM
clause and can be chained to perform multi-level UNNEST
.
You can also use a new type of index, the Array Index, to allow querying with UNNEST
more efficiently.
Couchbase Lite currently supports inner UNNEST only.
|
Syntax
The syntax for UNNEST
is shown below:
unnestClause = UNNEST expr ( ‘AS’? alias)?
|
Examples
For examples of using Array Indexes in conjunction with UNNEST
, see Array Index.
We are also accessing the current database using the shorthand notation _
— see the FROM clause for more on data source selection and Query Parameters for more on parameterized queries.
The following examples will use the example JSON document below to query results from:
{
"Name":"Sam",
"contacts":[
{
"type":"primary",
"address":{"street":"1 St","city":"San Pedro","state":"CA"},
"phones":[
{"type":"home","number":"310-123-4567"},
{"type":"mobile","number":"310-123-6789"}
]
},
{
"type":"secondary",
"address":{"street":"5 St","city":"Seattle","state":"WA"},
"phones":[
{"type":"home","number":"206-123-4567"},
{"type":"mobile","number":"206-123-6789"}
]
}
],
"likes":["soccer","travel"]
}
Using the document above we can perform queries on a single nested array like so:
SELECT name, like FROM _ UNNEST likes as like WHERE like = "travel"
The query above will produce the following output from the document:
{"name": "Sam", "like": "travel"}
You can perform similar operations on nested arrays:
SELECT name, contact.type, phone.number
FROM profiles
UNNEST contacts as contact
UNNEST contact.phones as phone
WHERE phone.type = "mobile"
The query above will then produce the following output:
{"name": "Sam", "type": "primary", "number": "310-123-6789"}
{"name": "Sam", "type": "secondary", "number": "206-123-6789"}
The output demonstrates retrieval of both primary and secondary contact numbers listed as type "mobile"
.
Array literals are not supported in CBL 3.2.1. Attempting to create a query with array literals will return an error. |
WHERE statement
Purpose
Specifies the selecion criteria used to filter results.
As with SQL, use the WHERE
statement to choose which documents are returned by your query.
Arguments
1 | WHERE evalates expression to a BOOLEAN value.
You can chain any number of Expressions in order to implement sophisticated filtering capabilities. |
See also — Operators for more on building expressions and Query Parameters for more on parameterized queries.
GROUP BY statement
Syntax
groupBy = grouping _( having )? (1)
grouping = GROUP BY expression( _ ',' _ expression )* (2)
having = HAVING expression (3)
Arguments
1 | The group by clause starts with the GROUP BY keyword followed by one or more expressions. |
2 | Grouping
The group by clause is normally used together with the aggregate functions (e.g. COUNT, MAX, MIN, SUM, AVG) |
3 | Having — allows you to filter the result based on aggregate functions — for example, HAVING count(empnum)>100 |
ORDER BY statement
Syntax
orderBy = ORDER BY ordering ( _ ',' _ ordering )* (1)
ordering = expression ( _ order )? (2)
order = ( ASC / DESC ) (3)
Arguments
1 | orderBy — The order by clause starts with the ORDER BY keyword followed by the ordering clause. |
2 | Ordering — The ordering clause specifies the properties or expressions to use for ordering the results. |
3 | Order — In each ordering clause, the sorting direction is specified using the optional ASC (ascending) or DESC (descending) directives. Default is ASC. |
LIMIT statement
OFFSET statement
Expressions
- In this section
-
Literals | Identifiers | Property Expressions | Any and Every Expressions | Parameter Expressions | Parenthesis Expressions
Expressions are references to identifiers that resolve to values. Categories of expression comprise the elements covered in this section (see above), together with Operators and Functions, which are covered in their own sections
Literals
Numeric
Purpose
Represents a numeric value. Numbers may be signed or unsigned digits. They have optional fractional and exponent components.
Example
SELECT value FROM db WHERE value = 10
SELECT value FROM db WHERE value = 0
SELECT value FROM db WHERE value = -10
SELECT value FROM db WHERE value = 10.25
SELECT value FROM db WHERE value = 10.25e2
SELECT value FROM db WHERE value = 10.25E2
SELECT value FROM db WHERE value = 10.25E+2
SELECT value FROM db WHERE value = 10.25E-2
String
Identifiers
Purpose
Identifiers provide symbolic references. Use them for example to identify: column alias names, database names, database alias names, property names, parameter names, function names, and FTS index names.
Property Expressions
Syntax
property = '*'| dataSourceName '.' _ '*' | propertyPath (1)
propertyPath = propertyName (
('.' _ propertyName ) | (2)
('[' _ INT_LITERAL _ ']' _ ) (3)
)* (4)
propertyName = IDENTIFIER
1 | Prefix the property expression with the data source name or alias to indicate its origin |
2 | Use dot syntax to refer to nested properties in the propertyPath. |
3 | Use bracket ([index]) syntax to refer to an item in an array. |
4 | Use the asterisk (*) character to represents all properties. This can only be used in the result list of the SELECT clause. |
Example
SELECT *
FROM db
WHERE contact.name = "daniel"
SELECT db.*
FROM db
WHERE collection.contact.name = "daniel"
SELECT collection.contact.address.city
FROM scope.collection
WHERE collection.contact.name = "daniel"
SELECT contact.address.city
FROM scope.collection
WHERE contact.name = "daniel"
SELECT contact.address.city, contact.phones[0]
FROM db
WHERE contact.name = "daniel"
Any and Every Expressions
Syntax
arrayExpression = (1)
anyEvery _ variableName (2)
_ IN _ expression (3)
_ SATISFIES _ expression (4)
END (5)
anyEvery = anyOrSome AND EVERY | anyOrSome | EVERY
anyOrSome = ANY | SOME
1 | The array expression starts with ANY/SOME , EVERY , or ANY/SOME AND EVERY , each of which has a different function as described below, and is terminated by END
|
2 | The variable name represents each item in the array. |
3 | The IN keyword is used for specifying the array to be evaluated. |
4 | The SATISFIES keyword is used for evaluating each item in the array. |
5 | END terminates the array expression. |
Parameter Expressions
Purpose
Parameter expressions specify a value to be assigned from the parameter map presented when executing the query.
If parameters are specified in the query string, but the parameter and value mapping is not specified in the query object, an error will be thrown when executing the query. |
Examples
SELECT name
FROM db
WHERE department = $department
let q = Query(
query: “SELECT name
WHERE department = $department”,
database: db
);
q.parameters =
Parameters().setValue(“E001”, forName: "department"); (1)
let result = q.execute();
1 | The query resolves to
SELECT name WHERE department = "E001" |
Parenthesis Expressions
Purpose
Use parentheses to group expressions together to make them more readable or to establish operator precedences.
Example
SELECT (value1 + value2) * value 3 (1)
FROM db
SELECT *
FROM db
WHERE ((value1 + value2) * value3) + value4 = 10
SELECT *
FROM db
WHERE (value1 = value2)
OR (value3 = value4) (2)
1 | Establish the desired operator precedence; do the addition before the multiplication |
2 | Clarify the conditional grouping |
Operators
- In this section
-
Binary Operators | Unary Operators | COLLATE Operators | CONDITIONAL Operator
Binary Operators
Maths
Op | Desc | Example |
---|---|---|
|
Add |
|
|
Subtract |
|
|
Multiply |
|
|
Divide — see note 1 |
|
|
Modulo |
|
1 If both operands are integers, integer division is used, but if one is a floating number, then float division is used.
This differs from Server SQL++, which performs float division regardless. Use DIV(x, y)
to force float division in CBL SQL++
Comparison Operators
Purpose
The comparison operators are used in the WHERE statement to specify the condition on which to match documents.
Op | Desc | Example |
---|---|---|
|
Equals |
|
|
Not Equal to |
|
|
Greater than |
|
|
Greater than or equal to |
|
|
Less than |
|
|
Less than or equal to |
|
|
Returns TRUE if the value is in the list or array of values specified by the right hand side expression; Otherwise returns FALSE. |
|
|
String wildcard pattern matching 2 comparison. Two wildcards are supported:
|
|
|
String matching using FTS see Full Text Search Functions |
|
|
Logically equivalent to v1>=X and v1⇐X+z |
|
|
Equal to null |
|
|
Not equal to null |
|
|
Equal to MISSING |
|
|
Not equal to MISSING |
|
|
IS NOT NULL AND MISSING |
|
|
IS NULL OR MISSING |
|
2 Matching is case-insensitive for ASCII characters, case-sensitive for non-ASCII.
3 Use of IS
and IS NOT
is limited to comparing NULL
and MISSING
values (this encompasses VALUED
).
This is different from QueryBuilder, in which they operate as equivalents of ==
and !=
.
OP | NON-NULL Value | NULL | MISSING |
---|---|---|---|
IS NULL |
FALSE |
TRUE |
MISSING |
IS NOT NULL |
TRUE |
FALSE |
MISSING |
IS MISSING |
FALSE |
FALSE |
TRUE |
IS NOT MISSING |
TRUE |
TRUE |
FALSE |
IS VALUED |
TRUE |
FALSE |
FALSE |
IS NOT VALUED |
FALSE |
TRUE |
TRUE |
Logical Operators
Purpose
Logical operators combine expressions using the following Boolean Logic Rules:
-
TRUE is TRUE, and FALSE is FALSE
-
Numbers 0 or 0.0 are FALSE
-
Arrays and dictionaries are FALSE
-
String and Blob are TRUE if the values are casted as a non-zero or FALSE if the values are casted as 0 or 0.0
-
NULL is FALSE
-
MISSING is MISSING
This is different from Server SQL++, where:
|
Op | Description | Example |
---|---|---|
|
Returns TRUE if the operand expressions evaluate to TRUE; otherwise FALSE. If an operand is MISSING and the other is TRUE returns MISSING, if the other operand is FALSE it returns FALSE. If an operand is NULL and the other is TRUE returns NULL, if the other operand is FALSE it returns FALSE. |
|
|
Returns TRUE if one of the operand expressions is evaluated to TRUE; otherwise returns FALSE. If an operand is MISSING, the operation will result in MISSING if the other operand is FALSE or TRUE if the other operand is TRUE. If an operand is NULL, the operation will result in NULL if the other operand is FALSE or TRUE if the other operand is TRUE. |
|
a | b | a AND b | a OR b |
---|---|---|---|
TRUE |
TRUE |
TRUE |
TRUE |
FALSE |
FALSE |
TRUE |
|
NULL |
FALSE 5-1 |
TRUE |
|
MISSING |
MISSING |
TRUE |
|
FALSE |
TRUE |
FALSE |
TRUE |
FALSE |
FALSE |
FALSE |
|
NULL |
FALSE |
FALSE 5-1 |
|
MISSING |
FALSE |
MISSING |
|
NULL |
TRUE |
FALSE 5-1 |
TRUE |
FALSE |
FALSE |
FALSE 5-1 |
|
NULL |
FALSE 5-1 |
FALSE 5-1 |
|
MISSING |
FALSE 5-2 |
MISSING 5-3 |
|
MISSING |
TRUE |
MISSING |
TRUE |
FALSE |
FALSE |
MISSING |
|
NULL |
FALSE 5-2 |
MISSING 5-3 |
|
MISSING |
MISSING |
MISSING |
This differs from Server SQL++ in the following instances: 5-1 Server will return: NULL instead of FALSE 5-2 Server will return: MISSING instead of FALSE 5-3 Server will return: NULL instead of MISSING |
Unary Operators
Purpose
Three unary operators are provided. They operate by modifying an expression, making it numerically positive or negative, or by logically negating its value (TRUE becomes FALSE).
Syntax
// UNARY_OP _ expr
Op | Description | Example |
---|---|---|
|
Positive value |
|
|
Negative value |
|
|
Logical Negate operator * |
|
* The NOT operator is often used in conjunction with operators such as IN, LIKE, MATCH, and BETWEEN operators.
NOT operation on NULL value returns NULL.
NOT operation on MISSING value returns MISSING.
a | NOT a |
---|---|
TRUE |
FALSE |
FALSE |
TRUE |
NULL |
FALSE |
MISSING |
MISSING |
COLLATE Operators
Usage
The collate operator is used in conjunction with string comparison expressions and ORDER BY clauses. It allows for one or more collations.
If multiple collations are used, the collations need to be specified in a parenthesis. When only one collation is used, the parenthesis is optional.
Collate is not supported by Server SQL++ |
Syntax
collate = COLLATE collation | '(' collation (_ collation )* ')'
collation = NO? (UNICODE | CASE | DIACRITICS) WB (1)
Arguments
1 | The available collation options are:
|
CONDITIONAL Operator
Purpose
The Conditional (or CASE
) operator evaluates conditional logic in a similar way to the IF/ELSE operator.
Syntax
CASE (expression) (WHEN expression THEN expression)+ (ELSE expression)? END (1)
CASE (expression)? (!WHEN expression)?
(WHEN expression THEN expression)+ (ELSE expression)? END (2)
Both Simple Case and Searched Case expressions are supported. The syntactic difference being that the Simple Case expression has an expression after the CASE keyword.
1 | Simple Case Expression
|
2 | Searched Case Expression
|
Functions
Syntax
The function syntax is the same as Java’s method syntax. It starts with the function name, followed by optional arguments inside parentheses.
function = functionName parenExprs
functionName = IDENTIFIER
parenExprs = '(' ( expression (_ ',' _ expression )* )? ')'
Aggregation Functions
Function | Description |
---|---|
|
Returns average value of the number values in the group |
|
Returns a count of all values in the group |
|
Returns the minimum value in the group |
|
Returns the maximum value in the group |
|
Returns the sum of all number values in the group |
Array Functions
Function | Description |
---|---|
|
Returns an array of the non-MISSING group values in the input expression, including NULL values. |
|
Returns the average of all non-NULL number values in the array; or NULL if there are none |
|
Returns TRUE if the value exists in the array; otherwise FALSE |
|
Returns the number of non-null values in the array |
|
Returns the first non-null value in the array |
|
Returns the largest non-NULL, non_MISSING value in the array |
|
Returns the smallest non-NULL, non_MISSING value in the array |
|
Returns the length of the array |
|
Returns the sum of all non-NULL numeric value in the array |
Conditional Functions
Function | Description |
---|---|
|
Returns the first non-MISSING value, or NULL if all values are MISSING |
|
Returns the first non-NULL and non-MISSING value, or NULL if all values are NULL or MISSING |
|
Returns the first non-NULL, or NULL if all values are NULL |
|
Returns |
|
Returns |
Date and Time Functions
Function | Arguments | Return Value |
---|---|---|
|
|
Returns an integer containing the converted date string into Epoch/UNIX milliseconds. |
|
|
Returns a date string representing the date string converted to UTC. The output date format follows the date format of the input date.
Returns |
|
|
Returns a date string representing the date string converted to the specified timezone. Returns |
|
|
Returns a date string representing the local date. Returns null if an invalid timestamp is provided. |
|
|
Returns a date string representing the date in UTC. Returns null if an invalid timestamp is provided. |
|
|
Returns a date string representing the date in the specified timezone in the specified format. If |
|
|
Returns an integer representing the elapsed time measured from The value is positive if Returns null if any of the parameters are invalid. |
|
|
Returns an integer representing the elapsed time measured from The value is positive if Returns null if any of the parameters are invalid. |
|
|
Returns an integer representing the calculation result as an Epoch/UNIX timestamp in milliseconds. Returns null if any of the parameters are invalid. |
|
|
Returns an integer representing the calculation result as an Epoch/UNIX timestamp in milliseconds. Returns null if any of the parameters are invalid. |
Full Text Search Functions
Function | Description | Example |
---|---|---|
|
Returns |
|
|
Returns a numeric value indicating how well the current query result matches the full-text query when performing the |
|
Maths Functions
Function | Description |
---|---|
|
Returns the absolute value of a number. |
|
Returns the arc cosine in radians. |
|
Returns the arcsine in radians. |
|
Returns the arctangent in radians. |
|
Returns the arctangent of expr1/expr2. |
|
Returns the smallest integer not less than the number. |
|
Returns the cosine value of the expression. |
|
Returns float division of expr1 and expr2. |
|
Converts radians to degrees. |
|
Returns base of natural logarithms. |
|
Returns expr value |
|
Returns largest integer not greater than the number. |
|
Returns integer division of expr1 and expr2. |
|
Returns log base e value. |
|
Returns log base 10 value. |
|
Return PI value. |
|
Returns expr1expr2 value. |
|
Returns degrees to radians. |
|
Returns the rounded value to the given number of integer digits to the right of the decimal point (left if digits is negative). Digits are 0 if not given. |
|
Returns rounded value to the given number of integer digits to the right of the decimal point (left if digits is negative). Digits are 0 if not given. The function uses Rounding to Nearest Even (Banker’s Rounding) convention which rounds midpoint values to the nearest even number (for example, both |
|
Returns -1 for negative, 0 for zero, and 1 for positive numbers. |
|
Returns sine value. |
|
Returns square root value. |
|
Returns tangent value. |
|
Returns a truncated number to the given number of integer digits to the right of the decimal point (left if digits is negative). Digits are 0 if not given. |
* The behavior of the ROUND() function is different from Server SQL++ ROUND(), which rounds the midpoint values using Rounding to Nearest Even convention.
Metadata Functions
Function | Description | Example |
---|---|---|
|
Returns a dictionary containing metadata properties including:
The optional dataSourceName identifies the database or the database alias name. |
|
Pattern Searching Functions
Function | Description |
---|---|
|
Returns TRUE if the string value contains any sequence that matches the regular expression pattern. |
|
Return TRUE if the string value exactly matches the regular expression pattern. |
|
Returns the first position of the occurrence of the regular expression pattern within the input string expression. Return -1 if no match is found. Position counting starts from zero. |
|
Returns new string with occurrences of pattern replaced with repl. If n is given, at the most n replacements are performed. If n is not given, all matching occurrences are replaced. |
String Functions
Function | Description |
---|---|
|
Returns true if the substring exists within the input string, otherwise returns false. |
|
Returns the length of a string. The length is defined as the number of characters within the string. |
|
Returns the lowercase string of the input string. |
|
Returns the string with all leading whitespace characters removed. |
|
Returns the string with all trailing whitespace characters removed. |
|
Returns the string with all leading and trailing whitespace characters removed. |
|
Returns the uppercase string of the input string. |
Type Checking Functions
Function | Description |
---|---|
|
Returns TRUE if expression is an array, otherwise returns MISSING, NULL or FALSE. |
|
Returns TRUE if expression is a Boolean, number, or string, otherwise returns MISSING, NULL or FALSE. |
|
Returns TRUE if expression is a Boolean, otherwise returns MISSING, NULL or FALSE. |
|
Returns TRUE if expression is a number, otherwise returns MISSING, NULL or FALSE. |
|
Returns TRUE if expression is an object (dictionary), otherwise returns MISSING, NULL or FALSE. |
|
Returns TRUE if expression is a string, otherwise returns MISSING, NULL or FALSE. |
|
Returns one of the following strings, based on the value of expression:
|
Type Conversion Functions
Function | Description |
---|---|
|
Returns MISSING if the value is MISSING. |
Returns NULL if the value is NULL. |
|
Returns the array itself. |
|
Returns all other values wrapped in an array. |
|
|
Returns MISSING if the value is MISSING. |
Returns NULL if the value is NULL. |
|
Returns an array of a single item if the value is an array. |
|
Returns an object of a single key/value pair if the value is an object. |
|
Returns boolean, numbers, or strings |
|
Returns NULL for all other values. |
|
|
Returns MISSING if the value is MISSING. |
Returns NULL if the value is NULL. |
|
Returns FALSE if the value is FALSE. |
|
Returns FALSE if the value is 0 or NaN. |
|
Returns FALSE if the value is an empty string, array, and object. |
|
Return TRUE for all other values. |
|
|
Returns MISSING if the value is MISSING. |
Returns NULL if the value is NULL. |
|
Returns 0 if the value is FALSE. |
|
Returns 1 if the value is TRUE. |
|
Returns NUMBER if the value is NUMBER. |
|
Returns NUMBER parsed from the string value. |
|
Returns NULL for all other values. |
|
|
Returns MISSING if the value is MISSING. |
Returns NULL if the value is NULL. |
|
Returns the object if the value is an object. |
|
Returns an empty object for all other values. |
|
|
Returns MISSING if the value is MISSING. |
Returns NULL if the value is NULL. |
|
Returns “false” if the value is FALSE. |
|
Returns “true” if the value is TRUE. |
|
Returns NUMBER in String if the value is NUMBER. |
|
Returns the string value if the value is a string. |
|
Returns NULL for all other values. |
QueryBuilder Differences
Couchbase Lite SQL++ Query supports all QueryBuilder features, except Predictive Query and Index. See Table 21 for the features supported by SQL++ but not by QueryBuilder.
Category | Components |
---|---|
Conditional Operator |
|
Array Functions |
|
Conditional Functions |
|
Pattern Matching Functions |
|
Type Checking Functions |
|
Type Conversion Functions |
|
Query Parameters
You can provide runtime parameters to your SQL++ query to make it more flexible.
To specify substitutable parameters within your query string prefix the name with $
, $type
— see: Example 18.
NSString *queryString = [NSString stringWithFormat:@"SELECT * FROM _ WHERE type = $type"]; (1)
CBLQuery *query = [self.database createQuery:queryString error: &error];
CBLQueryParameters *params = [[CBLQueryParameters alloc] init];
[params setString:@"hotel" forName:@"type"]; (2)
query.parameters = params;
CBLQueryResultSet *results = [query execute:&error];
1 | Define a parameter placeholder $type |
2 | Set the value of the $type parameter |