BSON_ EXTRACT_ BSON
Warning
SingleStore 9.0 gives you the opportunity to preview, evaluate, and provide feedback on new and upcoming features prior to their general availability. In the interim, SingleStore 8.9 is recommended for production workloads, which can later be upgraded to SingleStore 9.0.
On this page
Extracts and returns a BSON value from the BSON object, optionally at the specified path.
Syntax
BSON_EXTRACT_BSON(<bson_input> [, path_key_1, path_key_2, ..., path_key_n])
Arguments
-
<bson_
: A valid BSON object or an expression that evaluates to a valid BSON object.input> -
<path_
: (Optional) A comma-separated list of dictionary keys or array positions (zero-based index) that represent the path to the BSON object or the value to extract.key>
Return Type
A BSON value.
Remarks
-
If the
<path_
argument is not specified, the top-level document or value is returned.key> -
If the input is a top-level BSON value,
BSON_
returns the input value if theEXTRACT_ BSON() <path_
argument is not specified.key> Otherwise, it returns NULL
. -
If the specified
<path_
does not exist, returnskey> NULL
.
Examples
Note: The following examples explicitly cast string to BSON for clarity.
The examples use the following data set:
CREATE DATABASE dbTest;USE dbTest;CREATE TABLE bsonExample(a BSON);INSERT INTO bsonExample VALUES('{"doc":{"field1":42,"field2":true,"field3":"foobar","field4":[1,2,3],"child_doc":{"a":123}}}':>BSON);INSERT INTO bsonExample VALUES('{"doc":{"field1":28,"field2":false,"field3":"barfoo","field4":[7,8,9],"child_doc":{"a":42}}}':>BSON);INSERT INTO bsonExample VALUES('{"doc":{"field1":32,"field2":true,"field3":"hohoho","field4":[3,2,1],"child_doc":{"a":488}}}':>BSON);
The following example returns the top level document because the <path_
is not specified:
SELECT BSON_EXTRACT_BSON(a):>JSON AS Result FROM bsonExample;
+----------------------------------------------------------------------------------------------+
| Result |
+----------------------------------------------------------------------------------------------+
| {"doc":{"child_doc":{"a":123},"field1":42,"field2":true,"field3":"foobar","field4":[1,2,3]}} |
| {"doc":{"child_doc":{"a":42},"field1":28,"field2":false,"field3":"barfoo","field4":[7,8,9]}} |
| {"doc":{"child_doc":{"a":488},"field1":32,"field2":true,"field3":"hohoho","field4":[3,2,1]}} |
+----------------------------------------------------------------------------------------------+
The following example returns the BSON document at the specified path:
SELECT BSON_EXTRACT_BSON(a, 'doc','child_doc'):>JSON AS Result FROM bsonExample;
+-----------+
| Result |
+-----------+
| {"a":42} |
| {"a":488} |
| {"a":123} |
+-----------+
The following example returns the BSON array at the specified path:
SELECT BSON_EXTRACT_BSON(a, 'doc', 'field4'):>JSON AS Result FROM bsonExample;
+---------+
| Result |
+---------+
| [3,2,1] |
| [7,8,9] |
| [1,2,3] |
+---------+
The following example returns NULL
because the specified <path_
does not exist.
SELECT BSON_EXTRACT_BSON(a, 'doc', 'doc'):>JSON AS Result FROM bsonExample;
+--------+
| Result |
+--------+
| NULL |
| NULL |
| NULL |
+--------+
Last modified: May 8, 2024