The system provides various classes of functions to support operations on numeric, string, spatial, and temporal data. This document explains how to use these functions.
Syntax:
abs(numeric_value)
Computes the absolute value of the argument.
Example:
{ "v1": abs(2013), "v2": abs(-4036), "v3": abs(0), "v4": abs(float("-2013.5")), "v5": abs(double("-2013.593823748327284")) };
The expected result is:
{ "v1": 2013, "v2": 4036, "v3": 0, "v4": 2013.5, "v5": 2013.5938237483274 }
Syntax:
acos(numeric_value)
Computes the arc cosine value of the argument.
Example:
{ "v1": acos(1), "v2": acos(2), "v3": acos(0), "v4": acos(float("0.5")), "v5": acos(double("-0.5")) };
The expected result is:
{ "v1": 0.0, "v2": "NaN", "v3": 1.5707963267948966, "v4": 1.0471975511965979, "v5": 2.0943951023931957 }
Syntax:
asin(numeric_value)
Computes the arc sine value of the argument.
Example:
{ "v1": asin(1), "v2": asin(2), "v3": asin(0), "v4": asin(float("0.5")), "v5": asin(double("-0.5")) };
The expected result is:
{ "v1": 1.5707963267948966, "v2": "NaN", "v3": 0.0, "v4": 0.5235987755982989, "v5": -0.5235987755982989 }
Syntax:
atan(numeric_value)
Computes the arc tangent value of the argument.
Example:
{ "v1": atan(1), "v2": atan(2), "v3": atan(0), "v4": atan(float("0.5")), "v5": atan(double("1000")) };
The expected result is:
{ "v1": 0.7853981633974483, "v2": 1.1071487177940904, "v3": 0.0, "v4": 0.4636476090008061, "v5": 1.5697963271282298 }
Syntax:
atan2(numeric_value1, numeric_value2)
Computes the arc tangent value of numeric_value2/numeric_value1.
Example:
{ "v1": atan2(1, 2), "v2": atan2(0, 4), "v3": atan2(float("0.5"), double("-0.5")) };
The expected result is:
{ "v1": 0.4636476090008061, "v2": 0.0, "v3": 2.356194490192345 }
Syntax:
ceil(numeric_value)
Computes the smallest (closest to negative infinity) number with no fractional part that is not less than the value of the argument. If the argument is already equal to mathematical integer, then the result is the same as the argument.
Example:
{ "v1": ceil(2013), "v2": ceil(-4036), "v3": ceil(0.3), "v4": ceil(float("-2013.2")), "v5": ceil(double("-2013.893823748327284")) };
The expected result is:
{ "v1": 2013, "v2": -4036, "v3": 1.0, "v4": -2013.0, "v5": -2013.0 }
Syntax:
cos(numeric_value)
Computes the cosine value of the argument.
Example:
{ "v1": cos(1), "v2": cos(2), "v3": cos(0), "v4": cos(float("0.5")), "v5": cos(double("1000")) };
The expected result is:
{ "v1": 0.5403023058681398, "v2": -0.4161468365471424, "v3": 1.0, "v4": 0.8775825618903728, "v5": 0.562379076290703 }
Syntax:
exp(numeric_value)
Computes enumeric_value.
Example:
{ "v1": exp(1), "v2": exp(2), "v3": exp(0), "v4": exp(float("0.5")), "v5": exp(double("1000")) };
The expected result is:
{ "v1": 2.718281828459045, "v2": 7.38905609893065, "v3": 1.0, "v4": 1.6487212707001282, "v5": "Infinity" }
Syntax:
floor(numeric_value)
Computes the largest (closest to positive infinity) number with no fractional part that is not greater than the value. If the argument is already equal to mathematical integer, then the result is the same as the argument.
Example:
{ "v1": floor(2013), "v2": floor(-4036), "v3": floor(0.8), "v4": floor(float("-2013.2")), "v5": floor(double("-2013.893823748327284")) };
The expected result is:
{ "v1": 2013, "v2": -4036, "v3": 0.0, "v4": -2014.0, "v5": -2014.0 }
Syntax:
ln(numeric_value)
Computes logenumeric_value.
Example:
{ "v1": ln(1), "v2": ln(2), "v3": ln(0), "v4": ln(float("0.5")), "v5": ln(double("1000")) };
The expected result is:
{ "v1": 0.0, "v2": 0.6931471805599453, "v3": "-Infinity", "v4": -0.6931471805599453, "v5": 6.907755278982137 }
Syntax:
log(numeric_value)
Computes log10numeric_value.
Example:
{ "v1": log(1), "v2": log(2), "v3": log(0), "v4": log(float("0.5")), "v5": log(double("1000")) };
The expected result is:
{ "v1": 0.0, "v2": 0.3010299956639812, "v3": "-Infinity", "v4": -0.3010299956639812, "v5": 3.0 }
Syntax:
power(numeric_value1, numeric_value2)
Computes numeric_value1numeric_value2.
Example:
{ "v1": power(1, 2), "v3": power(0, 4), "v4": power(float("0.5"), double("-0.5")) };
The expected result is:
{ "v1": 1, "v3": 0, "v4": 1.4142135623730951 }
Syntax:
round(numeric_value)
Computes the number with no fractional part that is closest (and also closest to positive infinity) to the argument.
Example:
{ "v1": round(2013), "v2": round(-4036), "v3": round(0.8), "v4": round(float("-2013.256")), "v5": round(double("-2013.893823748327284")) };
The expected result is:
{ "v1": 2013, "v2": -4036, "v3": 1.0, "v4": -2013.0, "v5": -2014.0 }
Syntax:
sign(numeric_value)
Computes the sign of the argument.
Example:
{ "v1": sign(1), "v2": sign(2), "v3": sign(0), "v4": sign(float("0.5")), "v5": sign(double("-1000")) };
The expected result is:
{ "v1": 1, "v2": 1, "v3": 0, "v4": 1, "v5": -1 }
Syntax:
sin(numeric_value)
Computes the sine value of the argument.
Example:
{ "v1": sin(1), "v2": sin(2), "v3": sin(0), "v4": sin(float("0.5")), "v5": sin(double("1000")) };
The expected result is:
{ "v1": 0.8414709848078965, "v2": 0.9092974268256817, "v3": 0.0, "v4": 0.479425538604203, "v5": 0.8268795405320025 }
Syntax:
sqrt(numeric_value)
Computes the square root of the argument.
Example:
{ "v1": sqrt(1), "v2": sqrt(2), "v3": sqrt(0), "v4": sqrt(float("0.5")), "v5": sqrt(double("1000")) };
The expected result is:
{ "v1": 1.0, "v2": 1.4142135623730951, "v3": 0.0, "v4": 0.7071067811865476, "v5": 31.622776601683793 }
Syntax:
tan(numeric_value)
Computes the tangent value of the argument.
Example:
{ "v1": tan(1), "v2": tan(2), "v3": tan(0), "v4": tan(float("0.5")), "v5": tan(double("1000")) };
The expected result is:
{ "v1": 1.5574077246549023, "v2": -2.185039863261519, "v3": 0.0, "v4": 0.5463024898437905, "v5": 1.4703241557027185 }
Syntax:
trunc(numeric_value, number_digits)
Truncates the number to the given number of integer digits to the right of the decimal point (left if digits is negative). Digits is 0 if not given.
Example:
{ "v1": trunc(1, 1), "v2": trunc(2, -2), "v3": trunc(0.122, 2), "v4": trunc(float("11.52"), -1), "v5": trunc(double("1000.5252"), 3) };
The expected result is:
{ "v1": 1, "v2": 2, "v3": 0.12, "v4": 10.0, "v5": 1000.525 }
Syntax:
round_half_to_even(numeric_value, [precision])
Computes the closest numeric value to numeric_value that is a multiple of ten to the power of minus precision. precision is optional and by default value 0 is used.
Example:
{ "v1": round_half_to_even(2013), "v2": round_half_to_even(-4036), "v3": round_half_to_even(0.8), "v4": round_half_to_even(float("-2013.256")), "v5": round_half_to_even(double("-2013.893823748327284")), "v6": round_half_to_even(double("-2013.893823748327284"), 2), "v7": round_half_to_even(2013, 4), "v8": round_half_to_even(float("-2013.256"), 5) };
The expected result is:
{ "v1": 2013, "v2": -4036, "v3": 1.0, "v4": -2013.0, "v5": -2014.0, "v6": -2013.89, "v7": 2013, "v8": -2013.256 }
Syntax:
concat(string1, string2, ...)
Returns a concatenated string from arguments.
Example:
concat("test ", "driven ", "development");
The expected result is:
"test driven development"
Syntax:
contains(string, substring_to_contain)
Checks whether the string string contains the string substring_to_contain
Note: an n_gram index can be utilized for this function.
{ "v1": contains("I like x-phone", "phone"), "v2": contains("one", "phone") };
The expected result is:
{ "v1": true, "v2": false }
Syntax:
ends_with(string, substring_to_end_with)
Checks whether the string string ends with the string substring_to_end_with.
Example:
{ "v1": ends_with(" love product-b its shortcut_menu is awesome:)", ":)"), "v2": ends_with(" awsome:)", ":-)") };
The expected result is:
{ "v1": true, "v2": false }
Syntax:
initcap(string)
Converts a given string string so that the first letter of each word is uppercase and every other letter is lowercase. The function has an alias called “title”.
Example:
{ "v1": initcap("ASTERIXDB is here!"), "v2": title("ASTERIXDB is here!") };
The expected result is:
{ "v1": "Asterixdb Is Here!", "v2": "Asterixdb Is Here!" }
Syntax:
length(string)
Returns the length of the string string.
Example:
length("test string");
The expected result is:
11
Syntax:
lower(string)
Converts a given string string to its lowercase form.
Example:
lower("ASTERIXDB");
The expected result is:
"asterixdb"
Syntax:
ltrim(string[, chars]);
Returns a new string with all leading characters that appear in chars removed. By default, white space is the character to trim.
Example:
ltrim("me like x-phone", "eml");
The expected result is:
" like x-phone"
Syntax:
position(string, string_pattern)
Returns the first position of string_pattern within string.
Example:
{ "v1": position("ppphonepp", "phone"), "v2": position("hone", "phone") };
The expected result is:
{ "v1": 3, "v2": -1 }
Syntax:
regexp_contains(string, string_pattern[, string_flags])
Checks whether the strings string contains the regular expression pattern string_pattern (a Java regular expression pattern).
Example:
{ "v1": regexp_contains("pphonepp", "p*hone"), "v2": regexp_contains("hone", "p+hone") }
The expected result is:
{ "v1": true, "v2": false }
Syntax:
regexp_like(string, string_pattern[, string_flags])
Checks whether the string string exactly matches the regular expression pattern string_pattern (a Java regular expression pattern).
Example:
{ "v1": regexp_like(" can't stand acast the network is horrible:(", ".*acast.*"), "v2": regexp_like("acast", ".*acst.*") };
The expected result is:
{ "v1": true, "v2": false }
Syntax:
regexp_position(string, string_pattern[, string_flags])
Returns first position of the regular expression string_pattern (a Java regular expression pattern) within string.
Example:
{ "v1": regexp_position("pphonepp", "p*hone"), "v2": regexp_position("hone", "p+hone") };
The expected result is:
{ "v1": 1, "v2": -1 }
Syntax:
regexp_replace(string, string_pattern, string_replacement[, string_flags])
Checks whether the string string matches the given regular expression pattern string_pattern (a Java regular expression pattern), and replaces the matched pattern string_pattern with the new pattern string_replacement.
Example:
regexp_replace(" like x-phone the voicemail_service is awesome", " like x-phone", "like product-a")
The expected result is:
"like product-a the voicemail_service is awesome"
Syntax:
repeat(string, n)
Returns a string formed by repeating the input string n times.
Example:
repeat("test", 3);
The expected result is:
"testtesttest"
Syntax:
replace(string, search_string, replacement_string[, limit])
Finds occurrences of the given substring search_string in the input string string and replaces them with the new substring replacement_string.
Example:
{ "v1": replace(" like x-phone the voicemail_service is awesome", " like x-phone", "like product-a"), "v2": replace("x-phone and x-phone", "x-phone", "product-a", 1) };
The expected result is:
{ "v1": "like product-a the voicemail_service is awesome", "v2": "product-a and x-phone" }
Syntax:
rtrim(string[, chars]);
Returns a new string with all trailing characters that appear in chars removed. By default, white space is the character to trim.
Example:
{ "v1": rtrim("i like x-phone", "x-phone"), "v2": rtrim("i like x-phone", "onexph") };
The expected result is:
{ "v1": "i like ", "v2": "i like " }
Syntax:
split(string, sep)
Splits the input string into an array of substrings separated by the string sep.
Example:
split("test driven development", " ");
The expected result is:
[ "test", "driven", "development" ]
Syntax:
starts_with(string, substring_to_start_with)
Checks whether the string string starts with the string substring_to_start_with.
Example:
{ "v1" : starts_with(" like the plan, amazing", " like"), "v2" : starts_with("I like the plan, amazing", " like") };
The expected result is:
{ "v1": true, "v2": false }
Syntax:
substr(string, offset[, length])
Returns the substring from the given string string based on the given start offset offset with the optional length.
Example:
substr("test string", 6, 3);
The expected result is:
"str"
Syntax:
trim(string[, chars]);
Returns a new string with all leading characters that appear in chars removed. By default, white space is the character to trim.
Example:
trim("i like x-phone", "xphoen");
The expected result is:
" like "
Syntax:
upper(string)
Converts a given string string to its uppercase form.
Example:
upper("hello")
The expected result is:
"HELLO"
Syntax:
string_concat(array)
Concatenates an array of strings array into a single string.
Example:
string_concat(["ASTERIX", " ", "ROCKS!"]);
The expected result is:
"ASTERIX ROCKS!"
Syntax:
string_join(array, string)
Joins an array or multiset of strings array with the given separator string into a single string.
Example:
string_join(["ASTERIX", "ROCKS~"], "!! ");
The expected result is:
"ASTERIX!! ROCKS~"
Syntax:
string_to_codepoint(string)
Converts the string string to its code_based representation.
Example:
string_to_codepoint("Hello ASTERIX!");
The expected result is:
[ 72, 101, 108, 108, 111, 32, 65, 83, 84, 69, 82, 73, 88, 33 ]
Syntax:
codepoint_to_string(array)
Converts the ordered code_based representation array to the corresponding string.
Example:
codepoint_to_string([72, 101, 108, 108, 111, 32, 65, 83, 84, 69, 82, 73, 88, 33]);
The expected result is:
"Hello ASTERIX!"
Syntax:
substring_before(string, string_pattern)
Returns the substring from the given string string before the given pattern string_pattern.
Example:
substring_before(" like x-phone", "x-phone");
The expected result is:
" like "
Syntax:
substring_after(string, string_pattern);
Returns the substring from the given string string after the given pattern string_pattern.
Example:
substring_after(" like x-phone", "xph");
The expected result is:
"one"
Syntax:
parse_binary(string, encoding)
Creates a binary from an string encoded in encoding format.
Example:
[ parse_binary(“ABCDEF0123456789”,“hex”), parse_binary(“abcdef0123456789”,“HEX”), parse_binary(‘QXN0ZXJpeAE=’,“base64”) ];
The expected result is:
[ hex(“ABCDEF0123456789”), hex(“ABCDEF0123456789”), hex(“4173746572697801”) ]
Syntax:
print_binary(binary, encoding)
Prints a binary to the required encoding string format.
Example:
[ print_binary(hex("ABCDEF0123456789"), "base64"), print_binary(base64("q83vASNFZ4k="), "hex") ]
The expected result are:
[ "q83vASNFZ4k=", "ABCDEF0123456789" ]
Syntax:
binary_length(binary)
Returns the number of bytes storing the binary data.
Example:
binary_length(hex("00AA"))
The expected result is:
2
Syntax:
sub_binary(binary, offset[, length])
Returns the sub binary from the given binary based on the given start offset with the optional length.
Example:
sub_binary(hex("AABBCCDD"), 4);
The expected result is
hex("DD")
Syntax:
binary_concat(array)
Concatenates a binary array or multiset into a single binary.
Example:
binary_concat([hex(“42”), hex(""), hex(‘42’)]);
The expected result is
hex(“4242”)
Syntax:
create_point(x, y)
Creates the primitive type point using an x and y value.
Example:
{ "point": create_point(30.0,70.0) };
The expected result is:
{ "point": point("30.0,70.0") }
Syntax:
create_line(point1, point2)
Creates the primitive type line using point1 and point2.
Example:
{ "line": create_line(create_point(30.0,70.0), create_point(50.0,90.0)) };
The expected result is:
{ "line": line("30.0,70.0 50.0,90.0") }
Syntax:
create_rectangle(point1, point2)
Creates the primitive type rectangle using point1 and point2.
Example:
{ "rectangle": create_rectangle(create_point(30.0,70.0), create_point(50.0,90.0)) };
The expected result is:
{ "rectangle": rectangle("30.0,70.0 50.0,90.0") }
Syntax:
create_circle(point, radius)
Creates the primitive type circle using point and radius.
Example:
{ "circle": create_circle(create_point(30.0,70.0), 5.0) }
The expected result is:
{ "circle": circle("30.0,70.0 5.0") }
Syntax:
create_polygon(array)
Creates the primitive type polygon using the double values provided in the argument array. Each two consecutive double values represent a point starting from the first double value in the array. Note that at least six double values should be specified, meaning a total of three points.
Example:
{ "polygon": create_polygon([1.0,1.0,2.0,2.0,3.0,3.0,4.0,4.0]) };
The expected result is:
{ "polygon": polygon("1.0,1.0 2.0,2.0 3.0,3.0 4.0,4.0") }
Syntax:
get_x(point) or get_y(point)
Returns the x or y coordinates of a point point.
Example:
{ "x_coordinate": get_x(create_point(2.3,5.0)), "y_coordinate": get_y(create_point(2.3,5.0)) };
The expected result is:
{ "x_coordinate": 2.3, "y_coordinate": 5.0 }
Syntax:
get_points(spatial_object)
Returns an ordered array of the points forming the spatial object spatial_object.
Example:
get_points(create_polygon([1.0,1.0,2.0,2.0,3.0,3.0,4.0,4.0]))
The expected result is:
[ point("1.0,1.0"), point("2.0,2.0"), point("3.0,3.0"), point("4.0,4.0") ]
Syntax:
get_center(circle_expression) or get_radius(circle_expression)
Returns the center and the radius of a circle circle_expression, respectively.
Example:
{ "circle_radius": get_radius(create_circle(create_point(6.0,3.0), 1.0)), "circle_center": get_center(create_circle(create_point(6.0,3.0), 1.0)) };
The expected result is:
{ "circle_radius": 1.0, "circle_center": point("6.0,3.0") }
Syntax:
spatial_distance(point1, point2)
Returns the Euclidean distance between point1 and point2.
Example:
spatial_distance(point("47.44,80.65"), create_point(30.0,70.0));
The expected result is:
20.434678857275934
Syntax:
spatial_area(spatial_2d_expression)
Returns the spatial area of spatial_2d_expression.
Example:
spatial_area(create_circle(create_point(0.0,0.0), 5.0));
The expected result is:
78.53981625
Syntax:
spatial_intersect(spatial_object1, spatial_object2)
Checks whether @arg1 and @arg2 spatially intersect each other.
Example:
spatial_intersect(point("39.28,70.48"), create_rectangle(create_point(30.0,70.0), create_point(40.0,80.0)));
The expected result is:
true
Syntax:
spatial_cell(point1, point2, x_increment, y_increment)
Returns the grid cell that point1 belongs to.
Example:
spatial_cell(point("39.28,70.48"), create_point(20.0,50.0), 5.5, 6.0);
The expected result is:
rectangle("36.5,68.0 42.0,74.0");
AsterixDB supports queries with different similarity functions, including edit distance and Jaccard.
Syntax:
edit_distance(expression1, expression2)
Returns the edit distance of expression1 and expression2.
edit_distance("SuzannaTillson", "Suzanna Tilson");
The expected result is:
2
Syntax:
edit_distance_check(expression1, expression2, threshold)
Checks whether the edit distance of expression1 and expression2 is within a given threshold.
Arguments:
edit_distance_check("happy","hapr",2);
The expected result is:
[ true, 2 ]
Syntax:
edit_distance_contains(expression1, expression2, threshold)
Checks whether expression1 contains expression2 with an edit distance within a given threshold.
Arguments:
edit_distance_contains("happy","hapr",2);
The expected result is:
[ true, 1 ]
Syntax:
similarity_jaccard(array1, array2)
Returns the Jaccard similarity of array1 and array2.
Note: a keyword index can be utilized for this function.
similarity_jaccard([1,5,8,9], [1,5,9,10]);
The expected result is:
0.6
Syntax:
similarity_jaccard_check(array1, array2, threshold)
Checks whether array1 and array2 have a Jaccard similarity greater than or equal to threshold. Again, the “check” version of Jaccard is faster than the “non_check” version.
Arguments:
Note: a keyword index can be utilized for this function.
similarity_jaccard_check([1,5,8,9], [1,5,9,10], 0.6);
The expected result is:
[ false, 0.0 ]
Syntax:
word_tokens(string)
Returns an array of word tokens of string using non_alphanumeric characters as delimiters.
Example:
word_tokens("I like the phone, awesome!");
The expected result is:
[ "i", "like", "the", "phone", "awesome" ]
Syntax:
get_year/get_month/get_day/get_hour/get_minute/get_second/get_millisecond(temporal_value)
Accessors for accessing fields in a temporal value
Example:
{ "year": get_year(date("2010-10-30")), "month": get_month(datetime("1987-11-19T23:49:23.938")), "day": get_day(date("2010-10-30")), "hour": get_hour(time("12:23:34.930+07:00")), "min": get_minute(duration("P3Y73M632DT49H743M3948.94S")), "second": get_second(datetime("1987-11-19T23:49:23.938")), "ms": get_millisecond(duration("P3Y73M632DT49H743M3948.94S")) };
The expected result is:
{ "year": 2010, "month": 11, "day": 30, "hour": 5, "min": 28, "second": 23, "ms": 94 }
Syntax:
adjust_datetime_for_timezone(datetime, string)
Adjusts the given datetime datetime by applying the timezone information string.
Example:
adjust_datetime_for_timezone(datetime("2008-04-26T10:10:00"), "+08:00");
The expected result is:
"2008-04-26T18:10:00.000+08:00"
Syntax:
adjust_time_for_timezone(time, string)
Adjusts the given time time by applying the timezone information string.
Example:
adjust_time_for_timezone(get_time_from_datetime(datetime("2008-04-26T10:10:00")), "+08:00");
The expected result is:
"18:10:00.000+08:00"
Syntax:
calendar_duration_from_datetime(datetime, duration_value)
Gets a user_friendly representation of the duration duration_value based on the given datetime datetime.
Example:
calendar_duration_from_datetime( datetime("2016-03-26T10:10:00"), datetime("2016-03-26T10:10:00") - datetime("2011-01-01T00:00:00") );
The expected result is:
duration("P5Y2M24DT10H10M")
Syntax:
get_year_month_duration/get_day_time_duration(duration_value)
Extracts the correct duration subtype from duration_value.
Example:
get_year_month_duration(duration("P12M50DT10H"));
The expected result is:
year_month_duration("P1Y")
Syntax:
months_from_year_month_duration/milliseconds_from_day_time_duration(duration_value)
Extracts the number of months or the number of milliseconds from the duration subtype.
Example:
months_from_year_month_duration(get_year_month_duration(duration("P5Y7MT50M")));
The expected result is:
67
Syntax:
duration_from_months/duration_from_ms(number_value)
Creates a duration from number_value.
Example:
duration_from_months(8);
The expected result is:
duration("P8M")
Syntax:
duration_from_interval(interval_value)
Creates a duration from interval_value.
Example:
{ "dr1" : duration_from_interval(interval(date("2010-10-30"), date("2010-12-21"))), "dr2" : duration_from_interval(interval(datetime("2012-06-26T01:01:01.111"), datetime("2012-07-27T02:02:02.222"))), "dr3" : duration_from_interval(interval(time("12:32:38"), time("20:29:20"))), "dr4" : duration_from_interval(null) };
The expected result is:
{ "dr1": day_time_duration("P52D"), "dr2": day_time_duration("P31DT1H1M1.111S"), "dr3": day_time_duration("PT7H56M42S"), "dr4": null }
Syntax:
current_date()
Gets the current date.
Syntax:
current_time()
Get the current time
Syntax:
current_datetime()
Get the current datetime
Syntax:
get_date_from_datetime(datetime)
Gets the date value from the given datetime value datetime.
Syntax:
get_time_from_datetime(datetime)
Get the time value from the given datetime value datetime
Example:
get_time_from_datetime(datetime("2016-03-26T10:10:00"));
The expected result is:
time("10:10:00.000Z")
Syntax:
day_of_week(date)
Finds the day of the week for a given date (1_7)
Example:
day_of_week(datetime("2012-12-30T12:12:12.039Z"));
The expected result is:
7
Syntax:
date_from_unix_time_in_days(numeric_value)
Gets a date representing the time after numeric_value days since 1970_01_01.
Syntax:
datetime_from_unix_time_in_ms(numeric_value)
Gets a datetime representing the time after numeric_value milliseconds since 1970_01_01T00:00:00Z.
Syntax:
datetime_from_unix_time_in_secs(numeric_value)
Gets a datetime representing the time after numeric_value seconds since 1970_01_01T00:00:00Z.
datetime_from_date_time(date,time)
Syntax:
time_from_unix_time_in_ms(numeric_value)
Gets a time representing the time after numeric_value milliseconds since 00:00:00.000Z.
Example:
{ "date": date_from_unix_time_in_days(15800), "datetime": datetime_from_unix_time_in_ms(1365139700000), "time": time_from_unix_time_in_ms(3748) };
The expected result is:
{ "date": date("2013-04-05"), "datetime": datetime("2013-04-05T05:28:20.000Z"), "time": time("00:00:03.748Z") }
Syntax:
unix_time_from_date_in_days(date_value)
Gets an integer value representing the number of days since 1970_01_01 for date_value.
Syntax:
unix_time_from_datetime_in_ms(datetime_value)
Gets an integer value representing the time in milliseconds since 1970_01_01T00:00:00Z for datetime_value.
Syntax:
unix_time_from_datetime_in_secs(datetime_value)
Gets an integer value representing the time in seconds since 1970_01_01T00:00:00Z for datetime_value.
Syntax:
unix_time_from_time_in_ms(time_value)
Gets an integer value representing the time the milliseconds since 00:00:00.000Z for time_value.
Example:
{ "date": date_from_unix_time_in_days(15800), "datetime": datetime_from_unix_time_in_ms(1365139700000), "time": time_from_unix_time_in_ms(3748) }
The expected result is:
{ "date": date("2013-04-05"), "datetime": datetime("2013-04-05T05:28:20.000Z"), "time": time("00:00:03.748Z") }
parse_date/parse_time/parse_datetime(date,formatting_expression)
Example:
parse_time("30:30","m:s");
The expected result is:
time("00:30:30.000Z")
Syntax:
print_date/print_time/print_datetime(date,formatting_expression)
Creates a string representing a date/time/date_time value of the date using the formatting formatting_expression
Example:
print_time(time("00:30:30.000Z"),"m:s");
The expected result is:
"30:30"
Syntax:
get_interval_start/get_interval_end(interval)
Gets the start/end of the given interval.
Example:
{ "start": get_interval_start(interval_start_from_date("1984-01-01", "P1Y")), "end": get_interval_end(interval_start_from_date("1984-01-01", "P1Y")) };
The expected result is:
{ "start": date("1984_01_01"), "end": date("1985_01_01") }
Syntax:
get_interval_start_date/get_interval_start_datetime/get_interval_start_time/get_interval_end_date/get_interval_end_datetime/get_interval_end_time(interval)
Gets the start/end of the given interval for the specific date/datetime/time type.
Example:
{ "start1": get_interval_start_date(interval_start_from_date("1984-01-01", "P1Y")), "end1": get_interval_end_date(interval_start_from_date("1984-01-01", "P1Y")), "start2": get_interval_start_datetime(interval_start_from_datetime("1984-01-01T08:30:00.000", "P1Y1H")), "end2": get_interval_end_datetime(interval_start_from_datetime("1984-01-01T08:30:00.000", "P1Y1H")), "start3": get_interval_start_time(interval_start_from_time("08:30:00.000", "P1H")), "end3": get_interval_end_time(interval_start_from_time("08:30:00.000", "P1H")) };
The expected result is:
{ "start1": date("1984-01-01"), "end1": date("1985-01-01"), "start2": datetime("1984-01-01T08:30:00.000Z"), "end2": datetime("1985-01-01T09:30:00.000Z"), "start3": time("08:30:00.000Z"), "end3": time("09:30:00.000Z") }
Syntax:
get_overlapping_interval(interval1, interval2)
Gets the start/end of the given interval for the specific date/datetime/time type.
Example:
{ "overlap1": get_overlapping_interval(interval(time("11:23:39"), time("18:27:19")), interval(time("12:23:39"), time("23:18:00"))), "overlap2": get_overlapping_interval(interval(time("12:23:39"), time("18:27:19")), interval(time("07:19:39"), time("09:18:00"))), "overlap3": get_overlapping_interval(interval(date("1980-11-30"), date("1999-09-09")), interval(date("2013-01-01"), date("2014-01-01"))), "overlap4": get_overlapping_interval(interval(date("1980-11-30"), date("2099-09-09")), interval(date("2013-01-01"), date("2014-01-01"))), "overlap5": get_overlapping_interval(interval(datetime("1844-03-03T11:19:39"), datetime("2000-10-30T18:27:19")), interval(datetime("1989-03-04T12:23:39"), datetime("2009-10-10T23:18:00"))), "overlap6": get_overlapping_interval(interval(datetime("1989-03-04T12:23:39"), datetime("2000-10-30T18:27:19")), interval(datetime("1844-03-03T11:19:39"), datetime("1888-10-10T23:18:00"))) };
The expected result is:
{ "overlap1": interval(time("12:23:39.000Z"), time("18:27:19.000Z")), "overlap2": null, "overlap3": null, "overlap4": interval(date("2013-01-01"), date("2014_01_01")), "overlap5": interval(datetime("1989-03-04T12:23:39.000Z"), datetime("2000-10-30T18:27:19.000Z")), "overlap6": null }
Syntax:
interval_bin(time_to_bin, time_bin_anchor, duration_bin_size)
Returns the interval value representing the bin containing the time_to_bin value.
Example:
{ "bin1": interval_bin(date("2010-10-30"), date("1990-01-01"), year_month_duration("P1Y")), "bin2": interval_bin(datetime("1987-11-19T23:49:23.938"), datetime("1990-01-01T00:00:00.000Z"), year_month_duration("P6M")), "bin3": interval_bin(time("12:23:34.930+07:00"), time("00:00:00"), day_time_duration("PT1M")), "bin4": interval_bin(datetime("1987-11-19T23:49:23.938"), datetime("2013-01-01T00:00:00.000"), day_time_duration("PT24H")) };
The expected result is:
{ "bin1": interval(date("2010-01-01"),date("2011-01-01")), "bin2": interval(datetime("1987-07-01T00:00:00.000Z"), datetime("1988-01-01T00:00:00.000Z")), "bin3": interval(time("05:23:00.000Z"), time("05:24:00.000Z")), "bin4": interval(datetime("1987-11-19T00:00:00.000Z"), datetime("1987-11-20T00:00:00.000Z")) }
Syntax:
interval_start_from_date/time/datetime(date/time/datetime, duration)
Construct an interval value by the given starting date/time/datetime and the duration that the interval lasts.
Example:
{ "interval1": interval_start_from_date("1984-01-01", "P1Y"), "interval2": interval_start_from_time(time("02:23:28.394"), "PT3H24M"), "interval3": interval_start_from_datetime("1999-09-09T09:09:09.999", duration("P2M30D")) };
The expectecd result is:
{ "interval1": interval(date("1984-01-01"), date("1985-01-01")), "interval2": interval(time("02:23:28.394Z"), time("05:47:28.394Z")), "interval3": interval(datetime("1999-09-09T09:09:09.999Z"), datetime("1999-12-09T09:09:09.999Z")) }
Return Value:
Syntax:
overlap_bins(interval, time_bin_anchor, duration_bin_size)
Returns an ordered list of interval values representing each bin that is overlapping the interval.
Example:
{ "timebins": overlap_bins(interval(time("17:23:37"), time("18:30:21")), time("00:00:00"), day_time_duration("PT30M")), "datebins": overlap_bins(interval(date("1984-03-17"), date("2013-08-22")), date("1990-01-01"), year_month_duration("P10Y")), "datetimebins": overlap_bins(interval(datetime("1800-01-01T23:59:48.938"), datetime("2015-07-26T13:28:30.218")), datetime("1900-01-01T00:00:00.000"), year_month_duration("P100Y")) };
The expected result is:
{ "timebins": [ interval(time("17:00:00.000Z"), time("17:30:00.000Z")), interval(time("17:30:00.000Z"), time("18:00:00.000Z")), interval(time("18:00:00.000Z"), time("18:30:00.000Z")), interval(time("18:30:00.000Z"), time("19:00:00.000Z")) ], "datebins": [ interval(date("1980-01-01"), date("1990-01-01")), interval(date("1990-01-01"), date("2000-01-01")), interval(date("2000-01-01"), date("2010-01-01")), interval(date("2010-01-01"), date("2020-01-01")) ], "datetimebins": [ interval(datetime("1800-01-01T00:00:00.000Z"), datetime("1900-01-01T00:00:00.000Z")), interval(datetime("1900-01-01T00:00:00.000Z"), datetime("2000-01-01T00:00:00.000Z")), interval(datetime("2000-01-01T00:00:00.000Z"), datetime("2100-01-01T00:00:00.000Z")) ] };
Syntax:
interval_before(interval1, interval2) interval_after(interval1, interval2)
These two functions check whether an interval happens before/after another interval.
Examples:
{ "interval_before": interval_before(interval(date("2000-01-01"), date("2005-01-01")), interval(date("2005-05-01"), date("2012-09-09"))), "interval_after": interval_after(interval(date("2005-05-01"), date("2012-09-09")), interval(date("2000-01-01"), date("2005-01-01"))) };
The expected result is:
{ "interval_before": true, "interval_after": true }
Syntax:
interval_covers(interval1, interval2) interval_covered_by(interval1, interval2)
These two functions check whether one interval covers the other interval.
a boolean value. Specifically, interval_covers(interval1, interval2) is true if and only if
interval1.start <= interval2.start AND interval1.end >= interval2.end
interval_covered_by(interval1, interval2) is true if and only if
interval2.start <= interval1.start AND interval2.end >= interval1.end
missing if the argument is a missing value,
Examples:
{ "interval_covers": interval_covers(interval(date("2000-01-01"), date("2005-01-01")), interval(date("2000-03-01"), date("2004-09-09"))), "interval_covered_by": interval_covered_by(interval(date("2006-08-01"), date("2007-03-01")), interval(date("2004-09-10"), date("2012-08-01"))) };
The expected result is:
{ "interval_covers": true, "interval_covered_by": true }
Syntax:
interval_overlaps(interval1, interval2) interval_overlapped_by(interval1, interval2)
These functions check whether two intervals overlap with each other.
interval1.start < interval2.start AND interval2.end > interval1.end AND interval1.end > interval2.start
interval_overlapped_by(interval1, interval2) is true if and only if
interval2.start < interval1.start AND interval1.end > interval2.end AND interval2.end > interval1.start
Note that interval_overlaps and interval_overlapped_by are following the Allen’s relations on the definition of overlap.
Examples:
{ "overlaps": interval_overlaps(interval(date("2000-01-01"), date("2005-01-01")), interval(date("2004-05-01"), date("2012-09-09"))), "overlapped_by": interval_overlapped_by(interval(date("2006-08-01"), date("2007-03-01")), interval(date("2004-05-01"), date("2012-09-09")))) };
The expected result is:
{ "overlaps": true, "overlapped_by": true }
Note that interval_overlapping is not an Allen’s Relation, but syntactic sugar we added for the case that the intersect of two intervals is not empty. Basically this function returns true if any of these functions return true: interval_overlaps, interval_overlapped_by, interval_covers, or interval_covered_by.
Syntax:
interval_overlapping(interval1, interval2)
This functions check whether two intervals share any points with each other.
a boolean value. Specifically, interval_overlapping(interval1, interval2) is true if
interval1.start < interval2.end AND interval1.end > interval2.start
missing if the argument is a missing value,
Examples:
{ "overlapping1": interval_overlapping(interval(date("2000-01-01"), date("2005-01-01")), interval(date("2004-05-01"), date("2012-09-09"))), "overlapping2": interval_overlapping(interval(date("2006-08-01"), date("2007-03-01")), interval(date("2004-09-10"), date("2006-12-31"))) };
The expected result is:
{ "overlapping1": true, "overlapping2": true }
Syntax:
interval_meets(interval1, interval2) interval_met_by(interval1, interval2)
These two functions check whether an interval meets with another interval.
Examples:
{ "meets": interval_meets(interval(date("2000-01-01"), date("2005-01-01")), interval(date("2005-01-01"), date("2012-09-09"))), "metby": interval_met_by(interval(date("2006-08-01"), date("2007-03-01")), interval(date("2004-09-10"), date("2006-08-01"))) };
The expected result is:
{ "meets": true, "metby": true }
Syntax:
interval_starts(interval1, interval2) interval_started_by(interval1, interval2)
These two functions check whether one interval starts with the other interval.
interval1.start = interval2.start AND interval1.end <= interval2.end
interval_started_by(interval1, interval2) returns true if and only if
interval1.start = interval2.start AND interval2.end <= interval1.end
Examples:
{ "interval_starts": interval_starts(interval(date("2000-01-01"), date("2005-01-01")), interval(date("2000-01-01"), date("2012-09-09"))), "interval_started_by": interval_started_by(interval(date("2006-08-01"), date("2007-03-01")), interval(date("2006-08-01"), date("2006-08-02"))) };
The expected result is:
{ "interval_starts": true, "interval_started_by": true }
Syntax:
interval_ends(interval1, interval2) interval_ended_by(interval1, interval2)
These two functions check whether one interval ends with the other interval.
a boolean value. Specifically, interval_ends(interval1, interval2) returns true if and only if
interval1.end = interval2.end AND interval1.start >= interval2.start
interval_ended_by(interval1, interval2) returns true if and only if
interval2.end = interval1.end AND interval2.start >= interval1.start
missing if the argument is a missing value,
Examples:
{ "interval_ends": interval_ends(interval(date("2000-01-01"), date("2005-01-01")), interval(date("1998-01-01"), date("2005-01-01"))), "interval_ended_by": interval_ended_by(interval(date("2006-08-01"), date("2007-03-01")), interval(date("2006-09-10"), date("2007-03-01"))) };
The expected result is:
{ "interval_ends": true, "interval_ended_by": true }
Syntax:
get_object_fields(input_object)
Access the object field names, type and open status for a given object.
Example:
get_object_fields( { "id": 1, "project": "AsterixDB", "address": {"city": "Irvine", "state": "CA"}, "related": ["Hivestrix", "Preglix", "Apache VXQuery"] } );
The expected result is:
[ { "field-name": "id", "field-type": "INT64", "is-open": false }, { "field-name": "project", "field-type": "STRING", "is-open": false }, { "field-name": "address", "field-type": "RECORD", "is-open": false, "nested": [ { "field-name": "city", "field-type": "STRING", "is-open": false }, { "field-name": "state", "field-type": "STRING", "is-open": false } ] }, { "field-name": "related", "field-type": "ORDEREDLIST", "is-open": false, "list": [ { "field-type": "STRING" }, { "field-type": "STRING" }, { "field-type": "STRING" } ] } ]
]
Syntax:
get_object_field_value(input_object, string)
Access the field name given in the string_expression from the object_expression.
Example:
get_object_field_value({ "id": 1, "project": "AsterixDB", "address": {"city": "Irvine", "state": "CA"}, "related": ["Hivestrix", "Preglix", "Apache VXQuery"] }, "project" );
The expected result is:
"AsterixDB"
Syntax:
object_remove_fields(input_object, field_names)
Remove indicated fields from a object given a list of field names.
Return Value:
Example:
object_remove_fields( { "id":1, "project":"AsterixDB", "address":{"city":"Irvine", "state":"CA"}, "related":["Hivestrix", "Preglix", "Apache VXQuery"] }, [["address", "city"], "related"] );
The expected result is:
{ "id":1, "project":"AsterixDB", "address":{ "state": "CA" } }
Syntax:
object_add_fields(input_object, fields)
Add fields to a object given a list of field names.
Example:
object_add_fields( { "id":1, "project":"AsterixDB", "address":{"city":"Irvine", "state":"CA"}, "related":["Hivestrix", "Preglix", "Apache VXQuery"] }, [{"field-name":"employment_location", "field-value":create_point(30.0,70.0)}] );
The expected result is:
{ "id":1, "project":"AsterixDB", "address":{"city":"Irvine", "state":"CA"}, "related":["Hivestrix", "Preglix", "Apache VXQuery"] "employment_location": point("30.0,70.0") }
Syntax:
object_merge(object1, object2)
Merge two different objects into a new object.
Example:
object_merge( { "id":1, "project":"AsterixDB", "address":{"city":"Irvine", "state":"CA"}, "related":["Hivestrix", "Preglix", "Apache VXQuery"] }, { "user_id": 22, "employer": "UC Irvine", "employment_type": "visitor" } );
The expected result is:
{ "employment_type": "visitor", "address": { "city": "Irvine", "state": "CA" }, "related": [ "Hivestrix", "Preglix", "Apache VXQuery" ], "user_id": 22, "project": "AsterixDB", "employer": "UC Irvine", "id": 1 }
Syntax:
object_length(input_object)
Returns number of top-level fields in the given object
Example:
object_length( { "id": 1, "project": "AsterixDB", "address": {"city": "Irvine", "state": "CA"}, } );
The expected result is:
3
Syntax:
object_names(input_object)
Returns names of top-level fields in the given object
Example:
object_names( { "id": 1, "project": "AsterixDB", "address": {"city": "Irvine", "state": "CA"}, } );
The expected result is:
[ "id", "project", "address" ]
This section contains detailed descriptions of each SQL++ aggregate function (i.e., array function). Note that as described in the SQL++ query reference documentation, standard SQL aggregate functions (e.g., MIN, MAX, SUM, COUNT, and AVG) are not real functions in SQL++ but just syntactic sugars over corresponding SQL++ builtin aggregate functions (e.g., ARRAY_MIN, ARRAY_MAX, ARRAY_SUM, ARRAY_COUNT, and ARRAY_AVG).
Syntax:
array_count(collection)
Gets the number of non-null and non-missing items in the given collection.
Example:
array_count( ['hello', 'world', 1, 2, 3, null, missing] );
The expected result is:
5
Syntax:
array_avg(num_collection)
Gets the average value of the non-null and non-missing numeric items in the given collection.
Example:
array_avg( [1.2, 2.3, 3.4, 0, null] );
The expected result is:
1.725
Syntax:
array_sum(num_collection)
Gets the sum of non-null and non-missing items in the given collection.
Example:
array_sum( [1.2, 2.3, 3.4, 0, null, missing] );
The expected result is:
6.9
Syntax:
array_min(num_collection)
Gets the min value of non-null and non-missing comparable items in the given collection.
Example:
array_min( [1.2, 2.3, 3.4, 0, null, missing] );
The expected result is:
0.0
Syntax:
array_max(num_collection)
Gets the max value of the non-null and non-missing comparable items in the given collection.
Example:
array_max( [1.2, 2.3, 3.4, 0, null, missing] );
The expected result is:
3.4
Syntax:
coll_count(collection)
Gets the number of items in the given collection.
Example:
coll_count( [1, 2, null, missing] );
The expected result is:
4
Syntax:
coll_avg(num_collection)
Gets the average value of the numeric items in the given collection.
Example:
coll_avg( [100, 200, 300] );
The expected result is:
[ 200.0 ]
Syntax:
coll_sum(num_collection)
Gets the sum of the items in the given collection.
Example:
coll_sum( [100, 200, 300] );
The expected result is:
600
Syntax:
coll_min(num_collection)
Gets the min value of comparable items in the given collection.
Example:
coll_min( [10.2, 100, 5] );
The expected result is:
5.0
Syntax:
coll_max(num_collection)
Gets the max value of numeric items in the given collection.
Example:
coll_max( [10.2, 100, 5] );
The expected result is:
100.0
Syntax:
greatest(numeric_value1, numeric_value2, ...)
Computes the greatest value among arguments.
Example:
{ "v1": greatest(1, 2, 3), "v2": greatest(float("0.5"), double("-0.5"), 5000) };
The expected result is:
{ "v1": 3, "v2": 5000.0 }
Syntax:
least(numeric_value1, numeric_value2, ...)
Computes the least value among arguments.
Example:
{ "v1": least(1, 2, 3), "v2": least(float("0.5"), double("-0.5"), 5000) };
The expected result is:
{ "v1": 1, "v2": -0.5 }
Syntax:
is_array(expr)
Checks whether the given expression is evaluated to be an array value.
Example:
{ "a": is_array(true), "b": is_array(false), "c": isarray(null), "d": isarray(missing), "e": isarray("d"), "f": isarray(4.0), "g": isarray(5), "h": isarray(["1", 2]), "i": isarray({"a":1}) };
The expected result is:
{ "a": false, "b": false, "c": null, "e": false, "f": false, "g": false, "h": true, "i": false }
The function has an alias isarray.
Syntax:
is_atomic(expr)
Checks whether the given expression is evaluated to be a value of a primitive type.
Example:
{ "a": is_atomic(true), "b": is_atomic(false), "c": isatomic(null), "d": isatomic(missing), "e": isatomic("d"), "f": isatom(4.0), "g": isatom(5), "h": isatom(["1", 2]), "i": isatom({"a":1}) };
The expected result is:
{ "a": true, "b": true, "c": null, "e": true, "f": true, "g": true, "h": false, "i": false }
The function has three aliases: isatomic, is_atom, and isatom.
Syntax:
is_boolean(expr)
Checks whether the given expression is evaluated to be a boolean value.
Example:
{ "a": isboolean(true), "b": isboolean(false), "c": is_boolean(null), "d": is_boolean(missing), "e": isbool("d"), "f": isbool(4.0), "g": isbool(5), "h": isbool(["1", 2]), "i": isbool({"a":1}) };
The expected result is:
{ "a": true, "b": true, "c": null, "e": false, "f": false, "g": false, "h": false, "i": false }
The function has three aliases: isboolean, is_bool, and isbool.
Syntax:
is_number(expr)
Checks whether the given expression is evaluated to be a numeric value.
Example:
{ "a": is_number(true), "b": is_number(false), "c": isnumber(null), "d": isnumber(missing), "e": isnumber("d"), "f": isnum(4.0), "g": isnum(5), "h": isnum(["1", 2]), "i": isnum({"a":1}) };
The expected result is:
{ "a": false, "b": false, "c": null, "e": false, "f": true, "g": true, "h": false, "i": false }
The function has three aliases: isnumber, is_num, and isnum.
Syntax:
is_object(expr)
Checks whether the given expression is evaluated to be a object value.
Example:
{ "a": is_object(true), "b": is_object(false), "c": isobject(null), "d": isobject(missing), "e": isobj("d"), "f": isobj(4.0), "g": isobj(5), "h": isobj(["1", 2]), "i": isobj({"a":1}) };
The expected result is:
{ “a”: false, “b”: false, “c”: null, “e”: false, “f”: false, “g”: false, “h”: false, “i”: true }
The function has three aliases: isobject, is_obj, and isobj.
Syntax:
is_string(expr)
Checks whether the given expression is evaluated to be a string value.
Example:
{ "a": is_string(true), "b": isstring(false), "c": isstring(null), "d": isstr(missing), "e": isstr("d"), "f": isstr(4.0), "g": isstr(5), "h": isstr(["1", 2]), "i": isstr({"a":1}) };
The expected result is:
{ "a": false, "b": false, "c": null, "e": true, "f": false, "g": false, "h": false, "i": false }
The function has three aliases: isstring, is_str, and isstr.
Syntax:
is_null(expr)
Checks whether the given expression is evaluated to be a null value.
Example:
{ "v1": is_null(null), "v2": is_null(1), "v3": is_null(missing) };
The expected result is:
{ "v1": true, "v2": false }
The function has an alias isnull.
Syntax:
is_missing(expr)
Checks whether the given expression is evaluated to be a missing value.
Example:
{ "v1": is_missing(null), "v2": is_missing(1), "v3": is_missing(missing) };
The expected result is:
{ "v1": false, "v2": false, "v3": true }
The function has an alias ismissing.
Syntax:
is_unknown(expr)
Checks whether the given variable is a null value or a missing value.
Example:
{ "v1": is_unknown(null), "v2": is_unknown(1), "v3": is_unknown(missing) };
The expected result is:
{ "v1": true, "v2": false, "v3": true }
The function has an alias isunknown.
Syntax:
to_array(expr)
Converts input value to an array value
Example:
{ "v1": to_array("asterix"), "v2": to_array(["asterix"]), };
The expected result is:
{ "v1": ["asterix"], "v2": ["asterix"] }
The function has an alias toarray.
Syntax:
to_atomic(expr)
Converts input value to a primitive value
Example:
{ "v1": to_atomic("asterix"), "v2": to_atomic(["asterix"]), "v3": to_atomic([0, 1]), "v4": to_atomic({"value": "asterix"}), "v5": to_number({"x": 1, "y": 2}) };
The expected result is:
{ "v1": "asterix", "v2": "asterix", "v3": null, "v4": "asterix", "v5": null }
The function has three aliases: toatomic, to_atom, and toatom.
Syntax:
to_boolean(expr)
Converts input value to a boolean value
Example:
{ "v1": to_boolean(0), "v2": to_boolean(1), "v3": to_boolean(""), "v4": to_boolean("asterix") };
The expected result is:
{ "v1": false, "v2": true, "v3": false, "v4": true }
The function has three aliases: toboolean, to_bool, and tobool.
Syntax:
to_bigint(expr)
Converts input value to an integer value
Example:
{ "v1": to_bigint(false), "v2": to_bigint(true), "v3": to_bigint(10), "v4": to_bigint(float("1e100")), "v5": to_bigint(double("1e1000")), "v6": to_bigint("20") };
The expected result is:
{ "v1": 0, "v2": 1, "v3": 10, "v4": 9223372036854775807, "v5": 9223372036854775807, "v6": 20 }
The function has an alias tobigint.
Syntax:
to_double(expr)
Converts input value to a double value
Example:
{ "v1": to_double(false), "v2": to_double(true), "v3": to_double(10), "v4": to_double(11.5), "v5": to_double("12.5") };
The expected result is:
{ "v1": 0.0, "v2": 1.0, "v3": 10.0, "v4": 11.5, "v5": 12.5 }
The function has an alias todouble.
Syntax:
to_number(expr)
Converts input value to a numeric value
Example:
{ "v1": to_number(false), "v2": to_number(true), "v3": to_number(10), "v4": to_number(11.5), "v5": to_number("12.5") };
The expected result is:
{ "v1": 0, "v2": 1, "v3": 10, "v4": 11.5, "v5": 12.5 }
The function has three aliases: tonumber, to_num, and tonum.
Syntax:
to_object(expr)
Converts input value to an object value
Example:
{ "v1": to_object({"value": "asterix"}), "v2": to_object("asterix") };
The expected result is:
{ "v1": {"value": "asterix"}, "v2": {} }
The function has three aliases: toobject, to_obj, and toobj.
Syntax:
to_string(expr)
Converts input value to a string value
Example:
{ "v1": to_string(false), "v2": to_string(true), "v3": to_string(10), "v4": to_string(11.5), "v5": to_string("asterix") };
The expected result is:
{ "v1": "false", "v2": "true", "v3": "10", "v4": "11.5", "v5": "asterix" }
The function has three aliases: tostring, to_str, and tostr.
Syntax:
if_null(expression1, expression2, ... expressionN)
Finds first argument which value is not null and returns that value
Example:
{ "a": if_null(), "b": if_null(null), "c": if_null(null, "asterixdb"), "d": is_missing(if_null(missing)) };
The expected result is:
{ "a": null, "b": null, "c": "asterixdb", "d": true }
The function has an alias ifnull.
Syntax:
if_missing(expression1, expression2, ... expressionN)
Finds first argument which value is not missing and returns that value
Example:
{ "a": if_missing(), "b": if_missing(missing), "c": if_missing(missing, "asterixdb"), "d": if_missing(null, "asterixdb") };
The expected result is:
{ "a": null, "b": null, "c": "asterixdb", "d": null }
The function has an alias ifmissing.
Syntax:
if_missing_or_null(expression1, expression2, ... expressionN)
Finds first argument which value is not null or missing and returns that value
Example:
{ "a": if_missing_or_null(), "b": if_missing_or_null(null, missing), "c": if_missing_or_null(null, missing, "asterixdb") };
The expected result is:
{ "a": null, "b": null, "c": "asterixdb" }
The function has an alias ifmissingornull.
Syntax:
if_inf(expression1, expression2, ... expressionN)
Finds first argument which is a non-infinite (INF or-INF) number
Example:
{ "a": is_null(if_inf(null)), "b": is_missing(if_inf(missing)), "c": is_null(if_inf(double("INF"))), "d": if_inf(1, null, missing) ], "e": is_null(if_inf(null, missing, 1)) ], "f": is_missing(if_inf(missing, null, 1)) ], "g": if_inf(float("INF"), 1) ], "h": to_string(if_inf(float("INF"), double("NaN"), 1)) ] };
The expected result is:
{ "a": true, "b": true, "c": true, "d": 1, "e": true, "f": true, "g": 1, "h": "NaN" }
The function has an alias ifinf.
Syntax:
if_nan(expression1, expression2, ... expressionN)
Finds first argument which is a non-NaN number
Example:
{ "a": is_null(if_nan(null)), "b": is_missing(if_nan(missing)), "c": is_null(if_nan(double("NaN"))), "d": if_nan(1, null, missing) ], "e": is_null(if_nan(null, missing, 1)) ], "f": is_missing(if_nan(missing, null, 1)) ], "g": if_nan(float("NaN"), 1) ], "h": to_string(if_nan(float("NaN"), double("INF"), 1)) ] };
The expected result is:
{ "a": true, "b": true, "c": true, "d": 1, "e": true, "f": true, "g": 1, "h": "INF" }
The function has an alias ifnan.
Syntax:
if_nan_or_inf(expression1, expression2, ... expressionN)
Finds first argument which is a non-infinite (INF or-INF) and non-NaN number
Example:
{ "a": is_null(if_nan_or_inf(null)), "b": is_missing(if_nan_or_inf(missing)), "c": is_null(if_nan_or_inf(double("NaN"), double("INF"))), "d": if_nan_or_inf(1, null, missing) ], "e": is_null(if_nan_or_inf(null, missing, 1)) ], "f": is_missing(if_nan_or_inf(missing, null, 1)) ], "g": if_nan_or_inf(float("NaN"), float("INF"), 1) ], };
The expected result is:
{ "a": true, "b": true, "c": true, "d": 1, "e": true, "f": true, "g": 1 }
The function has an alias ifnanorinf.
Syntax:
len(array)
Returns the length of the array array.
Example:
len(["Hello", "World"])
The expected result is:
2
Syntax:
not(expr)
Inverts a boolean value
{ "v1": `not`(true), "v2": `not`(false), "v3": `not`(null), "v4": `not`(missing) };
The expected result is:
{ "v1": false, "v2": true, "v3": null }
Syntax:
range(start_numeric_value, end_numeric_value)
Generates a series of bigint values based start the start_numeric_value until the end_numeric_value.
range(0, 3);
The expected result is:
[ 0, 1, 2, 3 ]
Syntax:
switch_case( condition, case1, case1_result, case2, case2_result, ..., default, default_result )
Switches amongst a sequence of cases and returns the result of the first matching case. If no match is found, the result of the default case is returned.
switch_case( "a", "a", 0, "x", 1, "y", 2, "z", 3 );
The expected result is:
0
Example 2:
switch_case( "a", "x", 1, "y", 2, "z", 3 );
The expected result is:
3
Syntax:
deep_equal(expr1, expr2)
Assess the equality between two expressions of any type (e.g., object, arrays, or multiset). Two objects are deeply equal iff both their types and values are equal.
Example:
deep_equal( { "id":1, "project":"AsterixDB", "address":{"city":"Irvine", "state":"CA"}, "related":["Hivestrix", "Preglix", "Apache VXQuery"] }, { "id":1, "project":"AsterixDB", "address":{"city":"San Diego", "state":"CA"}, "related":["Hivestrix", "Preglix", "Apache VXQuery"] } );
The expected result is:
false