blob: f0dedb2e9df9995538900d273c9d1e2386a34016 [file] [log] [blame]
Ian Maxon41b806c2019-03-07 15:58:20 -08001<!DOCTYPE html>
2<!--
3 | Generated by Apache Maven Doxia Site Renderer 1.8.1 from target/generated-site/markdown/sqlpp/manual.md at 2019-03-07
4 | Rendered using Apache Maven Fluido Skin 1.7
5-->
6<html xmlns="http://www.w3.org/1999/xhtml" xml:lang="en" lang="en">
7 <head>
8 <meta charset="UTF-8" />
9 <meta name="viewport" content="width=device-width, initial-scale=1.0" />
10 <meta name="Date-Revision-yyyymmdd" content="20190307" />
11 <meta http-equiv="Content-Language" content="en" />
12 <title>AsterixDB &#x2013; The Query Language</title>
13 <link rel="stylesheet" href="../css/apache-maven-fluido-1.7.min.css" />
14 <link rel="stylesheet" href="../css/site.css" />
15 <link rel="stylesheet" href="../css/print.css" media="print" />
16 <script type="text/javascript" src="../js/apache-maven-fluido-1.7.min.js"></script>
17
18 </head>
19 <body class="topBarDisabled">
20 <div class="container-fluid">
21 <div id="banner">
22 <div class="pull-left"><a href=".././" id="bannerLeft"><img src="../images/asterixlogo.png" alt="AsterixDB"/></a></div>
23 <div class="pull-right"></div>
24 <div class="clear"><hr/></div>
25 </div>
26
27 <div id="breadcrumbs">
28 <ul class="breadcrumb">
29 <li id="publishDate">Last Published: 2019-03-07</li>
30 <li id="projectVersion" class="pull-right">Version: 0.9.4.1</li>
31 <li class="pull-right"><a href="../index.html" title="Documentation Home">Documentation Home</a></li>
32 </ul>
33 </div>
34 <div class="row-fluid">
35 <div id="leftColumn" class="span2">
36 <div class="well sidebar-nav">
37 <ul class="nav nav-list">
38 <li class="nav-header">Get Started - Installation</li>
39 <li><a href="../ncservice.html" title="Option 1: using NCService"><span class="none"></span>Option 1: using NCService</a></li>
40 <li><a href="../ansible.html" title="Option 2: using Ansible"><span class="none"></span>Option 2: using Ansible</a></li>
41 <li><a href="../aws.html" title="Option 3: using Amazon Web Services"><span class="none"></span>Option 3: using Amazon Web Services</a></li>
42 <li class="nav-header">AsterixDB Primer</li>
43 <li><a href="../sqlpp/primer-sqlpp.html" title="Option 1: using SQL++"><span class="none"></span>Option 1: using SQL++</a></li>
44 <li><a href="../aql/primer.html" title="Option 2: using AQL"><span class="none"></span>Option 2: using AQL</a></li>
45 <li class="nav-header">Data Model</li>
46 <li><a href="../datamodel.html" title="The Asterix Data Model"><span class="none"></span>The Asterix Data Model</a></li>
47 <li class="nav-header">Queries - SQL++</li>
48 <li class="active"><a href="#"><span class="none"></span>The SQL++ Query Language</a></li>
49 <li><a href="../sqlpp/builtins.html" title="Builtin Functions"><span class="none"></span>Builtin Functions</a></li>
50 <li class="nav-header">Queries - AQL</li>
51 <li><a href="../aql/manual.html" title="The Asterix Query Language (AQL)"><span class="none"></span>The Asterix Query Language (AQL)</a></li>
52 <li><a href="../aql/builtins.html" title="Builtin Functions"><span class="none"></span>Builtin Functions</a></li>
53 <li class="nav-header">API/SDK</li>
54 <li><a href="../api.html" title="HTTP API"><span class="none"></span>HTTP API</a></li>
55 <li><a href="../csv.html" title="CSV Output"><span class="none"></span>CSV Output</a></li>
56 <li class="nav-header">Advanced Features</li>
57 <li><a href="../aql/fulltext.html" title="Support of Full-text Queries"><span class="none"></span>Support of Full-text Queries</a></li>
58 <li><a href="../aql/externaldata.html" title="Accessing External Data"><span class="none"></span>Accessing External Data</a></li>
59 <li><a href="../feeds/tutorial.html" title="Support for Data Ingestion"><span class="none"></span>Support for Data Ingestion</a></li>
60 <li><a href="../udf.html" title="User Defined Functions"><span class="none"></span>User Defined Functions</a></li>
61 <li><a href="../aql/filters.html" title="Filter-Based LSM Index Acceleration"><span class="none"></span>Filter-Based LSM Index Acceleration</a></li>
62 <li><a href="../aql/similarity.html" title="Support of Similarity Queries"><span class="none"></span>Support of Similarity Queries</a></li>
63</ul>
64 <hr />
65 <div id="poweredBy">
66 <div class="clear"></div>
67 <div class="clear"></div>
68 <div class="clear"></div>
69 <div class="clear"></div>
70<a href=".././" title="AsterixDB" class="builtBy"><img class="builtBy" alt="AsterixDB" src="../images/asterixlogo.png" /></a>
71 </div>
72 </div>
73 </div>
74 <div id="bodyColumn" class="span10" >
75<!--
76 ! Licensed to the Apache Software Foundation (ASF) under one
77 ! or more contributor license agreements. See the NOTICE file
78 ! distributed with this work for additional information
79 ! regarding copyright ownership. The ASF licenses this file
80 ! to you under the Apache License, Version 2.0 (the
81 ! "License"); you may not use this file except in compliance
82 ! with the License. You may obtain a copy of the License at
83 !
84 ! http://www.apache.org/licenses/LICENSE-2.0
85 !
86 ! Unless required by applicable law or agreed to in writing,
87 ! software distributed under the License is distributed on an
88 ! "AS IS" BASIS, WITHOUT WARRANTIES OR CONDITIONS OF ANY
89 ! KIND, either express or implied. See the License for the
90 ! specific language governing permissions and limitations
91 ! under the License.
92 !-->
93<h1>The Query Language</h1>
94<ul>
95
96<li><a href="#Introduction">1. Introduction</a></li>
97<li><a href="#Expressions">2. Expressions</a>
98<ul>
99
100<li><a href="#Operator_expressions">Operator Expressions</a>
101<ul>
102
103<li><a href="#Arithmetic_operators">Arithmetic Operators</a></li>
104<li><a href="#Collection_operators">Collection Operators</a></li>
105<li><a href="#Comparison_operators">Comparison Operators</a></li>
106<li><a href="#Logical_operators">Logical Operators</a></li>
107</ul>
108</li>
109<li><a href="#Quantified_expressions">Quantified Expressions</a></li>
110<li><a href="#Path_expressions">Path Expressions</a></li>
111<li><a href="#Primary_expressions">Primary Expressions</a>
112<ul>
113
114<li><a href="#Literals">Literals</a></li>
115<li><a href="#Variable_references">Variable References</a></li>
116<li><a href="#Parenthesized_expressions">Parenthesized Expressions</a></li>
117<li><a href="#Function_call_expressions">Function call Expressions</a></li>
118<li><a href="#Case_expressions">Case Expressions</a></li>
119<li><a href="#Constructors">Constructors</a></li>
120</ul>
121</li>
122</ul>
123</li>
124<li><a href="#Queries">3. Queries</a>
125<ul>
126
127<li><a href="#Declarations">Declarations</a></li>
128<li><a href="#SELECT_statements">SELECT Statements</a></li>
129<li><a href="#Select_clauses">SELECT Clauses</a>
130<ul>
131
132<li><a href="#Select_element">Select Element/Value/Raw</a></li>
133<li><a href="#SQL_select">SQL-style Select</a></li>
134<li><a href="#Select_star">Select *</a></li>
135<li><a href="#Select_distinct">Select Distinct</a></li>
136<li><a href="#Unnamed_projections">Unnamed Projections</a></li>
137<li><a href="#Abbreviated_field_access_expressions">Abbreviated Field Access Expressions</a></li>
138</ul>
139</li>
140<li><a href="#Unnest_clauses">UNNEST Clauses</a>
141<ul>
142
143<li><a href="#Inner_unnests">Inner Unnests</a></li>
144<li><a href="#Left_outer_unnests">Left Outer Unnests</a></li>
145<li><a href="#Expressing_joins_using_unnests">Expressing Joins Using Unnests</a></li>
146</ul>
147</li>
148<li><a href="#From_clauses">FROM clauses</a>
149<ul>
150
151<li><a href="#Binding_expressions">Binding Expressions</a></li>
152<li><a href="#Multiple_from_terms">Multiple From Terms</a></li>
153<li><a href="#Expressing_joins_using_from_terms">Expressing Joins Using From Terms</a></li>
154<li><a href="#Implicit_binding_variables">Implicit Binding Variables</a></li>
155</ul>
156</li>
157<li><a href="#Join_clauses">JOIN Clauses</a>
158<ul>
159
160<li><a href="#Inner_joins">Inner Joins</a></li>
161<li><a href="#Left_outer_joins">Left Outer Joins</a></li>
162</ul>
163</li>
164<li><a href="#Group_By_clauses">GROUP BY Clauses</a>
165<ul>
166
167<li><a href="#Group_variables">Group Variables</a></li>
168<li><a href="#Implicit_group_key_variables">Implicit Group Key Variables</a></li>
169<li><a href="#Implicit_group_variables">Implicit Group Variables</a></li>
170<li><a href="#Aggregation_functions">Aggregation Functions</a></li>
171<li><a href="#SQL-92_aggregation_functions">SQL-92 Aggregation Functions</a></li>
172<li><a href="#SQL-92_compliant_gby">SQL-92 Compliant GROUP BY Aggregations</a></li>
173<li><a href="#Column_aliases">Column Aliases</a></li>
174</ul>
175</li>
176<li><a href="#Where_having_clauses">WHERE Clauses and HAVING Clauses</a></li>
177<li><a href="#Order_By_clauses">ORDER BY Clauses</a></li>
178<li><a href="#Limit_clauses">LIMIT Clauses</a></li>
179<li><a href="#With_clauses">WITH Clauses</a></li>
180<li><a href="#Let_clauses">LET Clauses</a></li>
181<li><a href="#Union_all">UNION ALL</a></li>
182<li><a href="#Vs_SQL-92">Differences from SQL-92</a></li>
183</ul>
184</li>
185<li><a href="#Errors">4. Errors</a>
186<ul>
187
188<li><a href="#Syntax_errors">Syntax Errors</a></li>
189<li><a href="#Identifier_resolution_errors">Identifier Resolution Errors</a></li>
190<li><a href="#Type_errors">Type Errors</a></li>
191<li><a href="#Resource_errors">Resource Errors</a></li>
192</ul>
193</li>
194<li><a href="#DDL_and_DML_statements">5. DDL and DML Statements</a>
195<ul>
196
197<li><a href="#Lifecycle_management_statements">Lifecycle Management Statements</a>
198<ul>
199
200<li><a href="#Dataverses">Dataverses</a></li>
201<li><a href="#Types">Types</a></li>
202<li><a href="#Datasets">Datasets</a></li>
203<li><a href="#Indices">Indices</a></li>
204<li><a href="#Functions">Functions</a></li>
205<li><a href="#Removal">Removal</a></li>
206<li><a href="#Load_statement">Load Statement</a></li>
207</ul>
208</li>
209<li><a href="#Modification_statements">Modification Statements</a>
210<ul>
211
212<li><a href="#Inserts">Inserts</a></li>
213<li><a href="#Upserts">Upserts</a></li>
214<li><a href="#Deletes">Deletes</a></li>
215</ul>
216</li>
217</ul>
218</li>
219<li><a href="#Reserved_keywords">Appendix 1. Reserved Keywords</a></li>
220<li><a href="#Performance_tuning">Appendix 2. Performance Tuning</a>
221<ul>
222
223<li><a href="#Parallelism_parameter">Parallelism Parameter</a></li>
224<li><a href="#Memory_parameters">Memory Parameters</a></li>
225</ul>
226</li>
227<li><a href="#Variable_bindings_and_name_resolution">Appendix 3. Variable Bindings and Name Resolution</a></li>
228</ul><!--
229 ! Licensed to the Apache Software Foundation (ASF) under one
230 ! or more contributor license agreements. See the NOTICE file
231 ! distributed with this work for additional information
232 ! regarding copyright ownership. The ASF licenses this file
233 ! to you under the Apache License, Version 2.0 (the
234 ! "License"); you may not use this file except in compliance
235 ! with the License. You may obtain a copy of the License at
236 !
237 ! http://www.apache.org/licenses/LICENSE-2.0
238 !
239 ! Unless required by applicable law or agreed to in writing,
240 ! software distributed under the License is distributed on an
241 ! "AS IS" BASIS, WITHOUT WARRANTIES OR CONDITIONS OF ANY
242 ! KIND, either express or implied. See the License for the
243 ! specific language governing permissions and limitations
244 ! under the License.
245 !-->
246
247<h1><a name="Introduction" id="Introduction">1. Introduction</a><font size="3" /></h1>
248<p>This document is intended as a reference guide to the full syntax and semantics of AsterixDB&#x2019;s query language, a SQL-based language for working with semistructured data. The language is a derivative of SQL++, a declarative query language for JSON data which is largely backwards compatible with SQL. SQL++ originated from research in the FORWARD project at UC San Diego, and it has much in common with SQL; some differences exist due to the different data models that the two languages were designed to serve. SQL was designed in the 1970&#x2019;s for interacting with the flat, schema-ified world of relational databases, while SQL++ is much newer and targets the nested, schema-optional (or even schema-less) world of modern NoSQL systems.</p>
249<p>In the context of Apache AsterixDB, the query language is intended for working with the Asterix Data Model (<a href="../datamodel.html">ADM</a>), a data model based on a superset of JSON with an enriched and flexible type system. New AsterixDB users are encouraged to read and work through the (much friendlier) guide &#x201c;<a href="primer-sqlpp.html">AsterixDB 101: An ADM and SQL++ Primer</a>&#x201d; before attempting to make use of this document. In addition, readers are advised to read through the <a href="../datamodel.html">Asterix Data Model (ADM) reference guide</a> first as well, as an understanding of the data model is a prerequisite to understanding the query language.</p>
250<p>In what follows, we detail the features of the query language in a grammar-guided manner. We list and briefly explain each of the productions in the query grammar, offering examples (and results) for clarity.</p><!--
251 ! Licensed to the Apache Software Foundation (ASF) under one
252 ! or more contributor license agreements. See the NOTICE file
253 ! distributed with this work for additional information
254 ! regarding copyright ownership. The ASF licenses this file
255 ! to you under the Apache License, Version 2.0 (the
256 ! "License"); you may not use this file except in compliance
257 ! with the License. You may obtain a copy of the License at
258 !
259 ! http://www.apache.org/licenses/LICENSE-2.0
260 !
261 ! Unless required by applicable law or agreed to in writing,
262 ! software distributed under the License is distributed on an
263 ! "AS IS" BASIS, WITHOUT WARRANTIES OR CONDITIONS OF ANY
264 ! KIND, either express or implied. See the License for the
265 ! specific language governing permissions and limitations
266 ! under the License.
267 !-->
268
269<h1><a name="Expressions" id="Expressions">2. Expressions</a></h1><!--
270 ! Licensed to the Apache Software Foundation (ASF) under one
271 ! or more contributor license agreements. See the NOTICE file
272 ! distributed with this work for additional information
273 ! regarding copyright ownership. The ASF licenses this file
274 ! to you under the Apache License, Version 2.0 (the
275 ! "License"); you may not use this file except in compliance
276 ! with the License. You may obtain a copy of the License at
277 !
278 ! http://www.apache.org/licenses/LICENSE-2.0
279 !
280 ! Unless required by applicable law or agreed to in writing,
281 ! software distributed under the License is distributed on an
282 ! "AS IS" BASIS, WITHOUT WARRANTIES OR CONDITIONS OF ANY
283 ! KIND, either express or implied. See the License for the
284 ! specific language governing permissions and limitations
285 ! under the License.
286 !-->
287
288<p>The query language is a highly composable expression language. Each expression in the query language returns zero or more data model instances. There are three major kinds of expressions. At the topmost level, an expression can be an OperatorExpression (similar to a mathematical expression) or a QuantifiedExpression (which yields a boolean value). Each will be detailed as we explore the full grammar of the language.</p>
289
290<div>
291<div>
292<pre class="source">Expression ::= OperatorExpression | QuantifiedExpression
293</pre></div></div>
294
295<p>Note that in the following text, words enclosed in angle brackets denote keywords that are not case-sensitive.</p>
296<div class="section">
297<h2><a name="Operator_Expressions"></a><a name="Operator_expressions" id="Operator_expressions">Operator Expressions</a></h2>
298<p>Operators perform a specific operation on the input values or expressions. The syntax of an operator expression is as follows:</p>
299
300<div>
301<div>
302<pre class="source">OperatorExpression ::= PathExpression
303 | Operator OperatorExpression
304 | OperatorExpression Operator (OperatorExpression)?
305 | OperatorExpression &lt;BETWEEN&gt; OperatorExpression &lt;AND&gt; OperatorExpression
306</pre></div></div>
307
308<p>The language provides a full set of operators that you can use within its statements. Here are the categories of operators:</p>
309<ul>
310
311<li><a href="#Arithmetic_operators">Arithmetic Operators</a>, to perform basic mathematical operations;</li>
312<li><a href="#Collection_operators">Collection Operators</a>, to evaluate expressions on collections or objects;</li>
313<li><a href="#Comparison_operators">Comparison Operators</a>, to compare two expressions;</li>
314<li><a href="#Logical_operators">Logical Operators</a>, to combine operators using Boolean logic.</li>
315</ul>
316<p>The following table summarizes the precedence order (from higher to lower) of the major unary and binary operators:</p>
317<table border="0" class="table table-striped">
318<thead>
319
320<tr class="a">
321<th> Operator </th>
322<th> Operation </th></tr>
323</thead><tbody>
324
325<tr class="b">
326<td> EXISTS, NOT EXISTS </td>
327<td> Collection emptiness testing </td></tr>
328<tr class="a">
329<td> ^ </td>
330<td> Exponentiation </td></tr>
331<tr class="b">
332<td> *, /, DIV, MOD (%) </td>
333<td> Multiplication, division, modulo </td></tr>
334<tr class="a">
335<td> +, - </td>
336<td> Addition, subtraction </td></tr>
337<tr class="b">
338<td> || </td>
339<td> String concatenation </td></tr>
340<tr class="a">
341<td> IS NULL, IS NOT NULL, IS MISSING, IS NOT MISSING, <br />IS UNKNOWN, IS NOT UNKNOWN, IS VALUED, IS NOT VALUED </td>
342<td> Unknown value comparison </td></tr>
343<tr class="b">
344<td> BETWEEN, NOT BETWEEN </td>
345<td> Range comparison (inclusive on both sides) </td></tr>
346<tr class="a">
347<td> =, !=, &lt;&gt;, &lt;, &gt;, &lt;=, &gt;=, LIKE, NOT LIKE, IN, NOT IN </td>
348<td> Comparison </td></tr>
349<tr class="b">
350<td> NOT </td>
351<td> Logical negation </td></tr>
352<tr class="a">
353<td> AND </td>
354<td> Conjunction </td></tr>
355<tr class="b">
356<td> OR </td>
357<td> Disjunction </td></tr>
358</tbody>
359</table>
360<p>In general, if any operand evaluates to a <tt>MISSING</tt> value, the enclosing operator will return <tt>MISSING</tt>; if none of operands evaluates to a <tt>MISSING</tt> value but there is an operand evaluates to a <tt>NULL</tt> value, the enclosing operator will return <tt>NULL</tt>. However, there are a few exceptions listed in <a href="#Comparison_operators">comparison operators</a> and <a href="#Logical_operators">logical operators</a>.</p>
361<div class="section">
362<h3><a name="Arithmetic_Operators"></a><a name="Arithmetic_operators" id="Arithmetic_operators">Arithmetic Operators</a></h3>
363<p>Arithmetic operators are used to exponentiate, add, subtract, multiply, and divide numeric values, or concatenate string values.</p>
364<table border="0" class="table table-striped">
365<thead>
366
367<tr class="a">
368<th> Operator </th>
369<th> Purpose </th>
370<th> Example </th></tr>
371</thead><tbody>
372
373<tr class="b">
374<td> +, - </td>
375<td> As unary operators, they denote a <br />positive or negative expression </td>
376<td> SELECT VALUE -1; </td></tr>
377<tr class="a">
378<td> +, - </td>
379<td> As binary operators, they add or subtract </td>
380<td> SELECT VALUE 1 + 2; </td></tr>
381<tr class="b">
382<td> * </td>
383<td> Multiply </td>
384<td> SELECT VALUE 4 * 2; </td></tr>
385<tr class="a">
386<td> / </td>
387<td> Divide (returns a value of type <tt>double</tt> if both operands are integers)</td>
388<td> SELECT VALUE 5 / 2; </td></tr>
389<tr class="b">
390<td> DIV </td>
391<td> Divide (returns an integer value if both operands are integers) </td>
392<td> SELECT VALUE 5 DIV 2; </td></tr>
393<tr class="a">
394<td> MOD (%) </td>
395<td> Modulo </td>
396<td> SELECT VALUE 5 % 2; </td></tr>
397<tr class="b">
398<td> ^ </td>
399<td> Exponentiation </td>
400<td> SELECT VALUE 2^3; </td></tr>
401<tr class="a">
402<td> || </td>
403<td> String concatenation </td>
404<td> SELECT VALUE &#x201c;ab&#x201d;||&#x201c;c&#x201d;||&#x201c;d&#x201d;; </td></tr>
405</tbody>
406</table></div>
407<div class="section">
408<h3><a name="Collection_Operators"></a><a name="Collection_operators" id="Collection_operators">Collection Operators</a></h3>
409<p>Collection operators are used for membership tests (IN, NOT IN) or empty collection tests (EXISTS, NOT EXISTS).</p>
410<table border="0" class="table table-striped">
411<thead>
412
413<tr class="a">
414<th> Operator </th>
415<th> Purpose </th>
416<th> Example </th></tr>
417</thead><tbody>
418
419<tr class="b">
420<td> IN </td>
421<td> Membership test </td>
422<td> SELECT * FROM ChirpMessages cm <br />WHERE cm.user.lang IN [&#x201c;en&#x201d;, &#x201c;de&#x201d;]; </td></tr>
423<tr class="a">
424<td> NOT IN </td>
425<td> Non-membership test </td>
426<td> SELECT * FROM ChirpMessages cm <br />WHERE cm.user.lang NOT IN [&#x201c;en&#x201d;]; </td></tr>
427<tr class="b">
428<td> EXISTS </td>
429<td> Check whether a collection is not empty </td>
430<td> SELECT * FROM ChirpMessages cm <br />WHERE EXISTS cm.referredTopics; </td></tr>
431<tr class="a">
432<td> NOT EXISTS </td>
433<td> Check whether a collection is empty </td>
434<td> SELECT * FROM ChirpMessages cm <br />WHERE NOT EXISTS cm.referredTopics; </td></tr>
435</tbody>
436</table></div>
437<div class="section">
438<h3><a name="Comparison_Operators"></a><a name="Comparison_operators" id="Comparison_operators">Comparison Operators</a></h3>
439<p>Comparison operators are used to compare values. The comparison operators fall into one of two sub-categories: missing value comparisons and regular value comparisons. The query language (and JSON) has two ways of representing missing information in a object - the presence of the field with a NULL for its value (as in SQL), and the absence of the field (which JSON permits). For example, the first of the following objects represents Jack, whose friend is Jill. In the other examples, Jake is friendless a la SQL, with a friend field that is NULL, while Joe is friendless in a more natural (for JSON) way, i.e., by not having a friend field.</p>
440<div class="section">
441<div class="section">
442<h5><a name="Examples"></a>Examples</h5>
443<p>{&#x201c;name&#x201d;: &#x201c;Jack&#x201d;, &#x201c;friend&#x201d;: &#x201c;Jill&#x201d;}</p>
444<p>{&#x201c;name&#x201d;: &#x201c;Jake&#x201d;, &#x201c;friend&#x201d;: NULL}</p>
445<p>{&#x201c;name&#x201d;: &#x201c;Joe&#x201d;}</p>
446<p>The following table enumerates all of the query language&#x2019;s comparison operators.</p>
447<table border="0" class="table table-striped">
448<thead>
449
450<tr class="a">
451<th> Operator </th>
452<th> Purpose </th>
453<th> Example </th></tr>
454</thead><tbody>
455
456<tr class="b">
457<td> IS NULL </td>
458<td> Test if a value is NULL </td>
459<td> SELECT * FROM ChirpMessages cm <br />WHERE cm.user.name IS NULL; </td></tr>
460<tr class="a">
461<td> IS NOT NULL </td>
462<td> Test if a value is not NULL </td>
463<td> SELECT * FROM ChirpMessages cm <br />WHERE cm.user.name IS NOT NULL; </td></tr>
464<tr class="b">
465<td> IS MISSING </td>
466<td> Test if a value is MISSING </td>
467<td> SELECT * FROM ChirpMessages cm <br />WHERE cm.user.name IS MISSING; </td></tr>
468<tr class="a">
469<td> IS NOT MISSING </td>
470<td> Test if a value is not MISSING </td>
471<td> SELECT * FROM ChirpMessages cm <br />WHERE cm.user.name IS NOT MISSING;</td></tr>
472<tr class="b">
473<td> IS UNKNOWN </td>
474<td> Test if a value is NULL or MISSING </td>
475<td> SELECT * FROM ChirpMessages cm <br />WHERE cm.user.name IS UNKNOWN; </td></tr>
476<tr class="a">
477<td> IS NOT UNKNOWN </td>
478<td> Test if a value is neither NULL nor MISSING </td>
479<td> SELECT * FROM ChirpMessages cm <br />WHERE cm.user.name IS NOT UNKNOWN;</td></tr>
480<tr class="b">
481<td> IS KNOWN (IS VALUED) </td>
482<td> Test if a value is neither NULL nor MISSING </td>
483<td> SELECT * FROM ChirpMessages cm <br />WHERE cm.user.name IS KNOWN; </td></tr>
484<tr class="a">
485<td> IS NOT KNOWN (IS NOT VALUED) </td>
486<td> Test if a value is NULL or MISSING </td>
487<td> SELECT * FROM ChirpMessages cm <br />WHERE cm.user.name IS NOT KNOWN; </td></tr>
488<tr class="b">
489<td> BETWEEN </td>
490<td> Test if a value is between a start value and <br />a end value. The comparison is inclusive <br />to both start and end values. </td>
491<td> SELECT * FROM ChirpMessages cm <br />WHERE cm.chirpId BETWEEN 10 AND 20;</td></tr>
492<tr class="a">
493<td> = </td>
494<td> Equality test </td>
495<td> SELECT * FROM ChirpMessages cm <br />WHERE cm.chirpId=10; </td></tr>
496<tr class="b">
497<td> != </td>
498<td> Inequality test </td>
499<td> SELECT * FROM ChirpMessages cm <br />WHERE cm.chirpId!=10;</td></tr>
500<tr class="a">
501<td> &lt;&gt; </td>
502<td> Inequality test </td>
503<td> SELECT * FROM ChirpMessages cm <br />WHERE cm.chirpId&lt;&gt;10;</td></tr>
504<tr class="b">
505<td> &lt; </td>
506<td> Less than </td>
507<td> SELECT * FROM ChirpMessages cm <br />WHERE cm.chirpId&lt;10; </td></tr>
508<tr class="a">
509<td> &gt; </td>
510<td> Greater than </td>
511<td> SELECT * FROM ChirpMessages cm <br />WHERE cm.chirpId&gt;10; </td></tr>
512<tr class="b">
513<td> &lt;= </td>
514<td> Less than or equal to </td>
515<td> SELECT * FROM ChirpMessages cm <br />WHERE cm.chirpId&lt;=10; </td></tr>
516<tr class="a">
517<td> &gt;= </td>
518<td> Greater than or equal to </td>
519<td> SELECT * FROM ChirpMessages cm <br />WHERE cm.chirpId&gt;=10; </td></tr>
520<tr class="b">
521<td> LIKE </td>
522<td> Test if the left side matches a<br /> pattern defined on the right<br /> side; in the pattern, &#x201c;%&#x201d; matches <br />any string while &#x201c;_&#x201d; matches <br /> any character. </td>
523<td> SELECT * FROM ChirpMessages cm <br />WHERE cm.user.name LIKE &#x201c;%Giesen%&#x201d;;</td></tr>
524<tr class="a">
525<td> NOT LIKE </td>
526<td> Test if the left side does not <br />match a pattern defined on the right<br /> side; in the pattern, &#x201c;%&#x201d; matches <br />any string while &#x201c;_&#x201d; matches <br /> any character. </td>
527<td> SELECT * FROM ChirpMessages cm <br />WHERE cm.user.name NOT LIKE &#x201c;%Giesen%&#x201d;;</td></tr>
528</tbody>
529</table>
530<p>The following table summarizes how the missing value comparison operators work.</p>
531<table border="0" class="table table-striped">
532<thead>
533
534<tr class="a">
535<th> Operator </th>
536<th> Non-NULL/Non-MISSING value </th>
537<th> NULL </th>
538<th> MISSING </th></tr>
539</thead><tbody>
540
541<tr class="b">
542<td> IS NULL </td>
543<td> FALSE </td>
544<td> TRUE </td>
545<td> MISSING </td></tr>
546<tr class="a">
547<td> IS NOT NULL </td>
548<td> TRUE </td>
549<td> FALSE </td>
550<td> MISSING </td></tr>
551<tr class="b">
552<td> IS MISSING </td>
553<td> FALSE </td>
554<td> FALSE </td>
555<td> TRUE </td></tr>
556<tr class="a">
557<td> IS NOT MISSING </td>
558<td> TRUE </td>
559<td> TRUE </td>
560<td> FALSE </td></tr>
561<tr class="b">
562<td> IS UNKNOWN </td>
563<td> FALSE </td>
564<td> TRUE </td>
565<td> TRUE </td></tr>
566<tr class="a">
567<td> IS NOT UNKNOWN </td>
568<td> TRUE </td>
569<td> FALSE </td>
570<td> FALSE</td></tr>
571<tr class="b">
572<td> IS KNOWN (IS VALUED) </td>
573<td> TRUE </td>
574<td> FALSE </td>
575<td> FALSE </td></tr>
576<tr class="a">
577<td> IS NOT KNOWN (IS NOT VALUED) </td>
578<td> FALSE </td>
579<td> TRUE </td>
580<td> TRUE </td></tr>
581</tbody>
582</table></div></div></div>
583<div class="section">
584<h3><a name="Logical_Operators"></a><a name="Logical_operators" id="Logical_operators">Logical Operators</a></h3>
585<p>Logical operators perform logical <tt>NOT</tt>, <tt>AND</tt>, and <tt>OR</tt> operations over Boolean values (<tt>TRUE</tt> and <tt>FALSE</tt>) plus <tt>NULL</tt> and <tt>MISSING</tt>.</p>
586<table border="0" class="table table-striped">
587<thead>
588
589<tr class="a">
590<th> Operator </th>
591<th> Purpose </th>
592<th> Example </th></tr>
593</thead><tbody>
594
595<tr class="b">
596<td> NOT </td>
597<td> Returns true if the following condition is false, otherwise returns false </td>
598<td> SELECT VALUE NOT TRUE; </td></tr>
599<tr class="a">
600<td> AND </td>
601<td> Returns true if both branches are true, otherwise returns false </td>
602<td> SELECT VALUE TRUE AND FALSE; </td></tr>
603<tr class="b">
604<td> OR </td>
605<td> Returns true if one branch is true, otherwise returns false </td>
606<td> SELECT VALUE FALSE OR FALSE; </td></tr>
607</tbody>
608</table>
609<p>The following table is the truth table for <tt>AND</tt> and <tt>OR</tt>.</p>
610<table border="0" class="table table-striped">
611<thead>
612
613<tr class="a">
614<th> A </th>
615<th> B </th>
616<th> A AND B </th>
617<th> A OR B </th></tr>
618</thead><tbody>
619
620<tr class="b">
621<td> TRUE </td>
622<td> TRUE </td>
623<td> TRUE </td>
624<td> TRUE </td></tr>
625<tr class="a">
626<td> TRUE </td>
627<td> FALSE </td>
628<td> FALSE </td>
629<td> TRUE </td></tr>
630<tr class="b">
631<td> TRUE </td>
632<td> NULL </td>
633<td> NULL </td>
634<td> TRUE </td></tr>
635<tr class="a">
636<td> TRUE </td>
637<td> MISSING </td>
638<td> MISSING </td>
639<td> TRUE </td></tr>
640<tr class="b">
641<td> FALSE </td>
642<td> FALSE </td>
643<td> FALSE </td>
644<td> FALSE </td></tr>
645<tr class="a">
646<td> FALSE </td>
647<td> NULL </td>
648<td> FALSE </td>
649<td> NULL </td></tr>
650<tr class="b">
651<td> FALSE </td>
652<td> MISSING </td>
653<td> FALSE </td>
654<td> MISSING </td></tr>
655<tr class="a">
656<td> NULL </td>
657<td> NULL </td>
658<td> NULL </td>
659<td> NULL </td></tr>
660<tr class="b">
661<td> NULL </td>
662<td> MISSING </td>
663<td> MISSING </td>
664<td> NULL </td></tr>
665<tr class="a">
666<td> MISSING </td>
667<td> MISSING </td>
668<td> MISSING </td>
669<td> MISSING </td></tr>
670</tbody>
671</table>
672<p>The following table demonstrates the results of <tt>NOT</tt> on all possible inputs.</p>
673<table border="0" class="table table-striped">
674<thead>
675
676<tr class="a">
677<th> A </th>
678<th> NOT A </th></tr>
679</thead><tbody>
680
681<tr class="b">
682<td> TRUE </td>
683<td> FALSE </td></tr>
684<tr class="a">
685<td> FALSE </td>
686<td> TRUE </td></tr>
687<tr class="b">
688<td> NULL </td>
689<td> NULL </td></tr>
690<tr class="a">
691<td> MISSING </td>
692<td> MISSING </td></tr>
693</tbody>
694</table></div></div>
695<div class="section">
696<h2><a name="Quantified_Expressions"></a><a name="Quantified_expressions" id="Quantified_expressions">Quantified Expressions</a></h2>
697
698<div>
699<div>
700<pre class="source">QuantifiedExpression ::= ( (&lt;ANY&gt;|&lt;SOME&gt;) | &lt;EVERY&gt; ) Variable &lt;IN&gt; Expression ( &quot;,&quot; Variable &quot;in&quot; Expression )*
701 &lt;SATISFIES&gt; Expression (&lt;END&gt;)?
702</pre></div></div>
703
704<p>Quantified expressions are used for expressing existential or universal predicates involving the elements of a collection.</p>
705<p>The following pair of examples illustrate the use of a quantified expression to test that every (or some) element in the set [1, 2, 3] of integers is less than three. The first example yields <tt>FALSE</tt> and second example yields <tt>TRUE</tt>.</p>
706<p>It is useful to note that if the set were instead the empty set, the first expression would yield <tt>TRUE</tt> (&#x201c;every&#x201d; value in an empty set satisfies the condition) while the second expression would yield <tt>FALSE</tt> (since there isn&#x2019;t &#x201c;some&#x201d; value, as there are no values in the set, that satisfies the condition).</p>
707<p>A quantified expression will return a <tt>NULL</tt> (or <tt>MISSING</tt>) if the first expression in it evaluates to <tt>NULL</tt> (or <tt>MISSING</tt>). A type error will be raised if the first expression in a quantified expression does not return a collection.</p>
708<div class="section">
709<div class="section">
710<div class="section">
711<h5><a name="Examples"></a>Examples</h5>
712
713<div>
714<div>
715<pre class="source">EVERY x IN [ 1, 2, 3 ] SATISFIES x &lt; 3
716SOME x IN [ 1, 2, 3 ] SATISFIES x &lt; 3
717</pre></div></div>
718</div></div></div></div>
719<div class="section">
720<h2><a name="Path_Expressions"></a><a name="Path_expressions" id="Path_expressions">Path Expressions</a></h2>
721
722<div>
723<div>
724<pre class="source">PathExpression ::= PrimaryExpression ( Field | Index )*
725Field ::= &quot;.&quot; Identifier
726Index ::= &quot;[&quot; Expression &quot;]&quot;
727</pre></div></div>
728
729<p>Components of complex types in the data model are accessed via path expressions. Path access can be applied to the result of a query expression that yields an instance of a complex type, for example, a object or array instance. For objects, path access is based on field names. For arrays, path access is based on (zero-based) array-style indexing. Attempts to access non-existent fields or out-of-bound array elements produce the special value <tt>MISSING</tt>. For multisets path access is also zero-based and returns an arbitrary multiset element if the index is within the size of the multiset or <tt>MISSING</tt> otherwise. Type errors will be raised for inappropriate use of a path expression, such as applying a field accessor to a numeric value.</p>
730<p>The following examples illustrate field access for a object, index-based element access for an array, and also a composition thereof.</p>
731<div class="section">
732<div class="section">
733<div class="section">
734<h5><a name="Examples"></a>Examples</h5>
735
736<div>
737<div>
738<pre class="source">({&quot;name&quot;: &quot;MyABCs&quot;, &quot;array&quot;: [ &quot;a&quot;, &quot;b&quot;, &quot;c&quot;]}).array
739
740([&quot;a&quot;, &quot;b&quot;, &quot;c&quot;])[2]
741
742({&quot;name&quot;: &quot;MyABCs&quot;, &quot;array&quot;: [ &quot;a&quot;, &quot;b&quot;, &quot;c&quot;]}).array[2]
743</pre></div></div>
744</div></div></div></div>
745<div class="section">
746<h2><a name="Primary_Expressions"></a><a name="Primary_expressions" id="Primary_expressions">Primary Expressions</a></h2>
747
748<div>
749<div>
750<pre class="source">PrimaryExpr ::= Literal
751 | VariableReference
752 | ParameterReference
753 | ParenthesizedExpression
754 | FunctionCallExpression
755 | CaseExpression
756 | Constructor
757</pre></div></div>
758
759<p>The most basic building block for any expression in the query langauge is PrimaryExpression. This can be a simple literal (constant) value, a reference to a query variable that is in scope, a parenthesized expression, a function call, or a newly constructed instance of the data model (such as a newly constructed object, array, or multiset of data model instances).</p></div>
760<div class="section">
761<h2><a name="Literals" id="Literals">Literals</a></h2>
762
763<div>
764<div>
765<pre class="source">Literal ::= StringLiteral
766 | IntegerLiteral
767 | FloatLiteral
768 | DoubleLiteral
769 | &lt;NULL&gt;
770 | &lt;MISSING&gt;
771 | &lt;TRUE&gt;
772 | &lt;FALSE&gt;
773StringLiteral ::= &quot;\&quot;&quot; (
774 &lt;EscapeQuot&gt;
775 | &lt;EscapeBslash&gt;
776 | &lt;EscapeSlash&gt;
777 | &lt;EscapeBspace&gt;
778 | &lt;EscapeFormf&gt;
779 | &lt;EscapeNl&gt;
780 | &lt;EscapeCr&gt;
781 | &lt;EscapeTab&gt;
782 | ~[&quot;\&quot;&quot;,&quot;\\&quot;])*
783 &quot;\&quot;&quot;
784 | &quot;\'&quot;(
785 &lt;EscapeApos&gt;
786 | &lt;EscapeBslash&gt;
787 | &lt;EscapeSlash&gt;
788 | &lt;EscapeBspace&gt;
789 | &lt;EscapeFormf&gt;
790 | &lt;EscapeNl&gt;
791 | &lt;EscapeCr&gt;
792 | &lt;EscapeTab&gt;
793 | ~[&quot;\'&quot;,&quot;\\&quot;])*
794 &quot;\'&quot;
795&lt;ESCAPE_Apos&gt; ::= &quot;\\\'&quot;
796&lt;ESCAPE_Quot&gt; ::= &quot;\\\&quot;&quot;
797&lt;EscapeBslash&gt; ::= &quot;\\\\&quot;
798&lt;EscapeSlash&gt; ::= &quot;\\/&quot;
799&lt;EscapeBspace&gt; ::= &quot;\\b&quot;
800&lt;EscapeFormf&gt; ::= &quot;\\f&quot;
801&lt;EscapeNl&gt; ::= &quot;\\n&quot;
802&lt;EscapeCr&gt; ::= &quot;\\r&quot;
803&lt;EscapeTab&gt; ::= &quot;\\t&quot;
804
805IntegerLiteral ::= &lt;DIGITS&gt;
806&lt;DIGITS&gt; ::= [&quot;0&quot; - &quot;9&quot;]+
807FloatLiteral ::= &lt;DIGITS&gt; ( &quot;f&quot; | &quot;F&quot; )
808 | &lt;DIGITS&gt; ( &quot;.&quot; &lt;DIGITS&gt; ( &quot;f&quot; | &quot;F&quot; ) )?
809 | &quot;.&quot; &lt;DIGITS&gt; ( &quot;f&quot; | &quot;F&quot; )
810DoubleLiteral ::= &lt;DIGITS&gt; &quot;.&quot; &lt;DIGITS&gt;
811 | &quot;.&quot; &lt;DIGITS&gt;
812</pre></div></div>
813
814<p>Literals (constants) in a query can be strings, integers, floating point values, double values, boolean constants, or special constant values like <tt>NULL</tt> and <tt>MISSING</tt>. The <tt>NULL</tt> value is like a <tt>NULL</tt> in SQL; it is used to represent an unknown field value. The special value <tt>MISSING</tt> is only meaningful in the context of field accesses; it occurs when the accessed field simply does not exist at all in a object being accessed.</p>
815<p>The following are some simple examples of literals.</p>
816<div class="section">
817<div class="section">
818<div class="section">
819<h5><a name="Examples"></a>Examples</h5>
820
821<div>
822<div>
823<pre class="source">'a string'
824&quot;test string&quot;
82542
826</pre></div></div>
827
828<p>Different from standard SQL, double quotes play the same role as single quotes and may be used for string literals in queries as well.</p></div></div></div>
829<div class="section">
830<h3><a name="Variable_References"></a><a name="Variable_references" id="Variable_references">Variable References</a></h3>
831
832<div>
833<div>
834<pre class="source">VariableReference ::= &lt;IDENTIFIER&gt; | &lt;DelimitedIdentifier&gt;
835&lt;IDENTIFIER&gt; ::= (&lt;LETTER&gt; | &quot;_&quot;) (&lt;LETTER&gt; | &lt;DIGIT&gt; | &quot;_&quot; | &quot;$&quot;)*
836&lt;LETTER&gt; ::= [&quot;A&quot; - &quot;Z&quot;, &quot;a&quot; - &quot;z&quot;]
837DelimitedIdentifier ::= &quot;`&quot; (&lt;EscapeQuot&gt;
838 | &lt;EscapeBslash&gt;
839 | &lt;EscapeSlash&gt;
840 | &lt;EscapeBspace&gt;
841 | &lt;EscapeFormf&gt;
842 | &lt;EscapeNl&gt;
843 | &lt;EscapeCr&gt;
844 | &lt;EscapeTab&gt;
845 | ~[&quot;`&quot;,&quot;\\&quot;])*
846 &quot;`&quot;
847</pre></div></div>
848
849<p>A variable in a query can be bound to any legal data model value. A variable reference refers to the value to which an in-scope variable is bound. (E.g., a variable binding may originate from one of the <tt>FROM</tt>, <tt>WITH</tt> or <tt>LET</tt> clauses of a <tt>SELECT</tt> statement or from an input parameter in the context of a function body.) Backticks, for example, `id`, are used for delimited identifiers. Delimiting is needed when a variable&#x2019;s desired name clashes with a keyword or includes characters not allowed in regular identifiers. More information on exactly how variable references are resolved can be found in the appendix section on Variable Resolution.</p>
850<div class="section">
851<div class="section">
852<h5><a name="Examples"></a>Examples</h5>
853
854<div>
855<div>
856<pre class="source">tweet
857id
858`SELECT`
859`my-function`
860</pre></div></div>
861</div></div></div>
862<div class="section">
863<h3><a name="Parameter_References"></a><a name="Parameter_references" id="Parameter_references">Parameter References</a></h3>
864
865<div>
866<div>
867<pre class="source">ParameterReference ::= NamedParameterReference | PositionalParameterReference
868NamedParameterReference ::= &quot;$&quot; (&lt;IDENTIFIER&gt; | &lt;DelimitedIdentifier&gt;)
869PositionalParameterReference ::= (&quot;$&quot; &lt;DIGITS&gt;) | &quot;?&quot;
870</pre></div></div>
871
872<p>A statement parameter is an external variable which value is provided through the <a href="../api.html#queryservice">statement execution API</a>. An error will be raised if the parameter is not bound at the query execution time. Positional parameter numbering starts at 1. &#x201c;?&#x201d; parameters are interpreted as $1, .. $N in the order in which they appear in the statement.</p>
873<div class="section">
874<div class="section">
875<h5><a name="Examples"></a>Examples</h5>
876
877<div>
878<div>
879<pre class="source">$id
880$1
881?
882</pre></div></div>
883</div></div></div>
884<div class="section">
885<h3><a name="Parenthesized_Expressions"></a><a name="Parenthesized_expressions" id="Parenthesized_expressions">Parenthesized Expressions</a></h3>
886
887<div>
888<div>
889<pre class="source">ParenthesizedExpression ::= &quot;(&quot; Expression &quot;)&quot; | Subquery
890</pre></div></div>
891
892<p>An expression can be parenthesized to control the precedence order or otherwise clarify a query. For composability, a subquery is also an parenthesized expression.</p>
893<p>The following expression evaluates to the value 2.</p>
894<div class="section">
895<div class="section">
896<h5><a name="Example"></a>Example</h5>
897
898<div>
899<div>
900<pre class="source">( 1 + 1 )
901</pre></div></div>
902</div></div></div>
903<div class="section">
904<h3><a name="Function_Call_Expressions"></a><a name="Function_call_expressions" id="Function_call_expressions">Function Call Expressions</a></h3>
905
906<div>
907<div>
908<pre class="source">FunctionCallExpression ::= FunctionName &quot;(&quot; ( Expression ( &quot;,&quot; Expression )* )? &quot;)&quot;
909</pre></div></div>
910
911<p>Functions are included in the query language, like most languages, as a way to package useful functionality or to componentize complicated or reusable computations. A function call is a legal query expression that represents the value resulting from the evaluation of its body expression with the given parameter bindings; the parameter value bindings can themselves be any expressions in the query language.</p>
912<p>The following example is a (built-in) function call expression whose value is 8.</p>
913<div class="section">
914<div class="section">
915<h5><a name="Example"></a>Example</h5>
916
917<div>
918<div>
919<pre class="source">length('a string')
920</pre></div></div>
921</div></div></div></div>
922<div class="section">
923<h2><a name="Case_Expressions"></a><a name="Case_expressions" id="Case_expressions">Case Expressions</a></h2>
924
925<div>
926<div>
927<pre class="source">CaseExpression ::= SimpleCaseExpression | SearchedCaseExpression
928SimpleCaseExpression ::= &lt;CASE&gt; Expression ( &lt;WHEN&gt; Expression &lt;THEN&gt; Expression )+ ( &lt;ELSE&gt; Expression )? &lt;END&gt;
929SearchedCaseExpression ::= &lt;CASE&gt; ( &lt;WHEN&gt; Expression &lt;THEN&gt; Expression )+ ( &lt;ELSE&gt; Expression )? &lt;END&gt;
930</pre></div></div>
931
932<p>In a simple <tt>CASE</tt> expression, the query evaluator searches for the first <tt>WHEN</tt> &#x2026; <tt>THEN</tt> pair in which the <tt>WHEN</tt> expression is equal to the expression following <tt>CASE</tt> and returns the expression following <tt>THEN</tt>. If none of the <tt>WHEN</tt> &#x2026; <tt>THEN</tt> pairs meet this condition, and an <tt>ELSE</tt> branch exists, it returns the <tt>ELSE</tt> expression. Otherwise, <tt>NULL</tt> is returned.</p>
933<p>In a searched CASE expression, the query evaluator searches from left to right until it finds a <tt>WHEN</tt> expression that is evaluated to <tt>TRUE</tt>, and then returns its corresponding <tt>THEN</tt> expression. If no condition is found to be <tt>TRUE</tt>, and an <tt>ELSE</tt> branch exists, it returns the <tt>ELSE</tt> expression. Otherwise, it returns <tt>NULL</tt>.</p>
934<p>The following example illustrates the form of a case expression.</p>
935<div class="section">
936<div class="section">
937<div class="section">
938<h5><a name="Example"></a>Example</h5>
939
940<div>
941<div>
942<pre class="source">CASE (2 &lt; 3) WHEN true THEN &quot;yes&quot; ELSE &quot;no&quot; END
943</pre></div></div>
944</div></div></div>
945<div class="section">
946<h3><a name="Constructors" id="Constructors">Constructors</a></h3>
947
948<div>
949<div>
950<pre class="source">Constructor ::= ArrayConstructor | MultisetConstructor | ObjectConstructor
951ArrayConstructor ::= &quot;[&quot; ( Expression ( &quot;,&quot; Expression )* )? &quot;]&quot;
952MultisetConstructor ::= &quot;{{&quot; ( Expression ( &quot;,&quot; Expression )* )? &quot;}}&quot;
953ObjectConstructor ::= &quot;{&quot; ( FieldBinding ( &quot;,&quot; FieldBinding )* )? &quot;}&quot;
954FieldBinding ::= Expression &quot;:&quot; Expression
955</pre></div></div>
956
957<p>A major feature of the query language is its ability to construct new data model instances. This is accomplished using its constructors for each of the model&#x2019;s complex object structures, namely arrays, multisets, and objects. Arrays are like JSON arrays, while multisets have bag semantics. Objects are built from fields that are field-name/field-value pairs, again like JSON.</p>
958<p>The following examples illustrate how to construct a new array with 4 items and a new object with 2 fields respectively. Array elements can be homogeneous (as in the first example), which is the common case, or they may be heterogeneous (as in the second example). The data values and field name values used to construct arrays, multisets, and objects in constructors are all simply query expressions. Thus, the collection elements, field names, and field values used in constructors can be simple literals or they can come from query variable references or even arbitrarily complex query expressions (subqueries). Type errors will be raised if the field names in an object are not strings, and duplicate field errors will be raised if they are not distinct.</p>
959<div class="section">
960<div class="section">
961<h5><a name="Examples"></a>Examples</h5>
962
963<div>
964<div>
965<pre class="source">[ 'a', 'b', 'c', 'c' ]
966
967[ 42, &quot;forty-two!&quot;, { &quot;rank&quot; : &quot;Captain&quot;, &quot;name&quot;: &quot;America&quot; }, 3.14159 ]
968
969{
970 'project name': 'Hyracks',
971 'project members': [ 'vinayakb', 'dtabass', 'chenli', 'tsotras', 'tillw' ]
972}
973</pre></div></div>
974<!--
975 ! Licensed to the Apache Software Foundation (ASF) under one
976 ! or more contributor license agreements. See the NOTICE file
977 ! distributed with this work for additional information
978 ! regarding copyright ownership. The ASF licenses this file
979 ! to you under the Apache License, Version 2.0 (the
980 ! "License"); you may not use this file except in compliance
981 ! with the License. You may obtain a copy of the License at
982 !
983 ! http://www.apache.org/licenses/LICENSE-2.0
984 !
985 ! Unless required by applicable law or agreed to in writing,
986 ! software distributed under the License is distributed on an
987 ! "AS IS" BASIS, WITHOUT WARRANTIES OR CONDITIONS OF ANY
988 ! KIND, either express or implied. See the License for the
989 ! specific language governing permissions and limitations
990 ! under the License.
991 !-->
992
993<h1><a name="Queries" id="Queries">3. Queries</a></h1>
994<p>A query can be any legal expression or <tt>SELECT</tt> statement. A query always ends with a semicolon.</p>
995
996<div>
997<div>
998<pre class="source">Query ::= (Expression | SelectStatement) &quot;;&quot;
999</pre></div></div>
1000<!--
1001 ! Licensed to the Apache Software Foundation (ASF) under one
1002 ! or more contributor license agreements. See the NOTICE file
1003 ! distributed with this work for additional information
1004 ! regarding copyright ownership. The ASF licenses this file
1005 ! to you under the Apache License, Version 2.0 (the
1006 ! "License"); you may not use this file except in compliance
1007 ! with the License. You may obtain a copy of the License at
1008 !
1009 ! http://www.apache.org/licenses/LICENSE-2.0
1010 !
1011 ! Unless required by applicable law or agreed to in writing,
1012 ! software distributed under the License is distributed on an
1013 ! "AS IS" BASIS, WITHOUT WARRANTIES OR CONDITIONS OF ANY
1014 ! KIND, either express or implied. See the License for the
1015 ! specific language governing permissions and limitations
1016 ! under the License.
1017 !-->
1018</div></div></div></div>
1019<div class="section">
1020<h2><a name="Declarations" id="Declarations">Declarations</a></h2>
1021
1022<div>
1023<div>
1024<pre class="source">DatabaseDeclaration ::= &quot;USE&quot; Identifier
1025</pre></div></div>
1026
1027<p>At the uppermost level, the world of data is organized into data namespaces called <b>dataverses</b>. To set the default dataverse for statements, the USE statement is provided.</p>
1028<p>As an example, the following statement sets the default dataverse to be &#x201c;TinySocial&#x201d;.</p>
1029<div class="section">
1030<div class="section">
1031<div class="section">
1032<h5><a name="Example"></a>Example</h5>
1033
1034<div>
1035<div>
1036<pre class="source">USE TinySocial;
1037</pre></div></div>
1038<!--
1039 ! Licensed to the Apache Software Foundation (ASF) under one
1040 ! or more contributor license agreements. See the NOTICE file
1041 ! distributed with this work for additional information
1042 ! regarding copyright ownership. The ASF licenses this file
1043 ! to you under the Apache License, Version 2.0 (the
1044 ! "License"); you may not use this file except in compliance
1045 ! with the License. You may obtain a copy of the License at
1046 !
1047 ! http://www.apache.org/licenses/LICENSE-2.0
1048 !
1049 ! Unless required by applicable law or agreed to in writing,
1050 ! software distributed under the License is distributed on an
1051 ! "AS IS" BASIS, WITHOUT WARRANTIES OR CONDITIONS OF ANY
1052 ! KIND, either express or implied. See the License for the
1053 ! specific language governing permissions and limitations
1054 ! under the License.
1055 !-->
1056
1057<p>When writing a complex query, it can sometimes be helpful to define one or more auxilliary functions that each address a sub-piece of the overall query. The declare function statement supports the creation of such helper functions. In general, the function body (expression) can be any legal query expression.</p>
1058
1059<div>
1060<div>
1061<pre class="source">FunctionDeclaration ::= &quot;DECLARE&quot; &quot;FUNCTION&quot; Identifier ParameterList &quot;{&quot; Expression &quot;}&quot;
1062ParameterList ::= &quot;(&quot; ( &lt;VARIABLE&gt; ( &quot;,&quot; &lt;VARIABLE&gt; )* )? &quot;)&quot;
1063</pre></div></div>
1064
1065<p>The following is a simple example of a temporary function definition and its use.</p></div>
1066<div class="section">
1067<h5><a name="Example"></a>Example</h5>
1068
1069<div>
1070<div>
1071<pre class="source">DECLARE FUNCTION friendInfo(userId) {
1072 (SELECT u.id, u.name, len(u.friendIds) AS friendCount
1073 FROM GleambookUsers u
1074 WHERE u.id = userId)[0]
1075 };
1076
1077SELECT VALUE friendInfo(2);
1078</pre></div></div>
1079
1080<p>For our sample data set, this returns:</p>
1081
1082<div>
1083<div>
1084<pre class="source">[
1085 { &quot;id&quot;: 2, &quot;name&quot;: &quot;IsbelDull&quot;, &quot;friendCount&quot;: 2 }
1086]
1087</pre></div></div>
1088<!--
1089 ! Licensed to the Apache Software Foundation (ASF) under one
1090 ! or more contributor license agreements. See the NOTICE file
1091 ! distributed with this work for additional information
1092 ! regarding copyright ownership. The ASF licenses this file
1093 ! to you under the Apache License, Version 2.0 (the
1094 ! "License"); you may not use this file except in compliance
1095 ! with the License. You may obtain a copy of the License at
1096 !
1097 ! http://www.apache.org/licenses/LICENSE-2.0
1098 !
1099 ! Unless required by applicable law or agreed to in writing,
1100 ! software distributed under the License is distributed on an
1101 ! "AS IS" BASIS, WITHOUT WARRANTIES OR CONDITIONS OF ANY
1102 ! KIND, either express or implied. See the License for the
1103 ! specific language governing permissions and limitations
1104 ! under the License.
1105 !-->
1106</div></div></div></div>
1107<div class="section">
1108<h2><a name="SELECT_Statements"></a><a name="SELECT_statements" id="SELECT_statements">SELECT Statements</a></h2>
1109<p>The following shows the (rich) grammar for the <tt>SELECT</tt> statement in the query language.</p>
1110
1111<div>
1112<div>
1113<pre class="source">SelectStatement ::= ( WithClause )?
1114 SelectSetOperation (OrderbyClause )? ( LimitClause )?
1115SelectSetOperation ::= SelectBlock (&lt;UNION&gt; &lt;ALL&gt; ( SelectBlock | Subquery ) )*
1116Subquery ::= &quot;(&quot; SelectStatement &quot;)&quot;
1117
1118SelectBlock ::= SelectClause
1119 ( FromClause ( LetClause )?)?
1120 ( WhereClause )?
1121 ( GroupbyClause ( LetClause )? ( HavingClause )? )?
1122 |
1123 FromClause ( LetClause )?
1124 ( WhereClause )?
1125 ( GroupbyClause ( LetClause )? ( HavingClause )? )?
1126 SelectClause
1127
1128SelectClause ::= &lt;SELECT&gt; ( &lt;ALL&gt; | &lt;DISTINCT&gt; )? ( SelectRegular | SelectValue )
1129SelectRegular ::= Projection ( &quot;,&quot; Projection )*
1130SelectValue ::= ( &lt;VALUE&gt; | &lt;ELEMENT&gt; | &lt;RAW&gt; ) Expression
1131Projection ::= ( Expression ( &lt;AS&gt; )? Identifier | &quot;*&quot; | Identifier &quot;.&quot; &quot;*&quot; )
1132
1133FromClause ::= &lt;FROM&gt; FromTerm ( &quot;,&quot; FromTerm )*
1134FromTerm ::= Expression (( &lt;AS&gt; )? Variable)?
1135 ( ( JoinType )? ( JoinClause | UnnestClause ) )*
1136
1137JoinClause ::= &lt;JOIN&gt; Expression (( &lt;AS&gt; )? Variable)? &lt;ON&gt; Expression
1138UnnestClause ::= ( &lt;UNNEST&gt; ) Expression
1139 ( &lt;AS&gt; )? Variable ( &lt;AT&gt; Variable )?
1140JoinType ::= ( &lt;INNER&gt; | &lt;LEFT&gt; ( &lt;OUTER&gt; )? )
1141
1142WithClause ::= &lt;WITH&gt; WithElement ( &quot;,&quot; WithElement )*
1143LetClause ::= (&lt;LET&gt; | &lt;LETTING&gt;) LetElement ( &quot;,&quot; LetElement )*
1144LetElement ::= Variable &quot;=&quot; Expression
1145WithElement ::= Variable &lt;AS&gt; Expression
1146
1147WhereClause ::= &lt;WHERE&gt; Expression
1148
1149GroupbyClause ::= &lt;GROUP&gt; &lt;BY&gt; Expression ( ( (&lt;AS&gt;)? Variable )?
1150 ( &quot;,&quot; Expression ( (&lt;AS&gt;)? Variable )? )* )
1151 ( &lt;GROUP&gt; &lt;AS&gt; Variable
1152 (&quot;(&quot; VariableReference &lt;AS&gt; Identifier
1153 (&quot;,&quot; VariableReference &lt;AS&gt; Identifier )* &quot;)&quot;)?
1154 )?
1155HavingClause ::= &lt;HAVING&gt; Expression
1156
1157OrderbyClause ::= &lt;ORDER&gt; &lt;BY&gt; Expression ( &lt;ASC&gt; | &lt;DESC&gt; )?
1158 ( &quot;,&quot; Expression ( &lt;ASC&gt; | &lt;DESC&gt; )? )*
1159LimitClause ::= &lt;LIMIT&gt; Expression ( &lt;OFFSET&gt; Expression )?
1160</pre></div></div>
1161
1162<p>In this section, we will make use of two stored collections of objects (datasets), <tt>GleambookUsers</tt> and <tt>GleambookMessages</tt>, in a series of running examples to explain <tt>SELECT</tt> queries. The contents of the example collections are as follows:</p>
1163<p><tt>GleambookUsers</tt> collection (or, dataset):</p>
1164
1165<div>
1166<div>
1167<pre class="source">[ {
1168 &quot;id&quot;:1,
1169 &quot;alias&quot;:&quot;Margarita&quot;,
1170 &quot;name&quot;:&quot;MargaritaStoddard&quot;,
1171 &quot;nickname&quot;:&quot;Mags&quot;,
1172 &quot;userSince&quot;:&quot;2012-08-20T10:10:00&quot;,
1173 &quot;friendIds&quot;:[2,3,6,10],
1174 &quot;employment&quot;:[{
1175 &quot;organizationName&quot;:&quot;Codetechno&quot;,
1176 &quot;start-date&quot;:&quot;2006-08-06&quot;
1177 },
1178 {
1179 &quot;organizationName&quot;:&quot;geomedia&quot;,
1180 &quot;start-date&quot;:&quot;2010-06-17&quot;,
1181 &quot;end-date&quot;:&quot;2010-01-26&quot;
1182 }],
1183 &quot;gender&quot;:&quot;F&quot;
1184},
1185{
1186 &quot;id&quot;:2,
1187 &quot;alias&quot;:&quot;Isbel&quot;,
1188 &quot;name&quot;:&quot;IsbelDull&quot;,
1189 &quot;nickname&quot;:&quot;Izzy&quot;,
1190 &quot;userSince&quot;:&quot;2011-01-22T10:10:00&quot;,
1191 &quot;friendIds&quot;:[1,4],
1192 &quot;employment&quot;:[{
1193 &quot;organizationName&quot;:&quot;Hexviafind&quot;,
1194 &quot;startDate&quot;:&quot;2010-04-27&quot;
1195 }]
1196},
1197{
1198 &quot;id&quot;:3,
1199 &quot;alias&quot;:&quot;Emory&quot;,
1200 &quot;name&quot;:&quot;EmoryUnk&quot;,
1201 &quot;userSince&quot;:&quot;2012-07-10T10:10:00&quot;,
1202 &quot;friendIds&quot;:[1,5,8,9],
1203 &quot;employment&quot;:[{
1204 &quot;organizationName&quot;:&quot;geomedia&quot;,
1205 &quot;startDate&quot;:&quot;2010-06-17&quot;,
1206 &quot;endDate&quot;:&quot;2010-01-26&quot;
1207 }]
1208} ]
1209</pre></div></div>
1210
1211<p><tt>GleambookMessages</tt> collection (or, dataset):</p>
1212
1213<div>
1214<div>
1215<pre class="source">[ {
1216 &quot;messageId&quot;:2,
1217 &quot;authorId&quot;:1,
1218 &quot;inResponseTo&quot;:4,
1219 &quot;senderLocation&quot;:[41.66,80.87],
1220 &quot;message&quot;:&quot; dislike x-phone its touch-screen is horrible&quot;
1221},
1222{
1223 &quot;messageId&quot;:3,
1224 &quot;authorId&quot;:2,
1225 &quot;inResponseTo&quot;:4,
1226 &quot;senderLocation&quot;:[48.09,81.01],
1227 &quot;message&quot;:&quot; like product-y the plan is amazing&quot;
1228},
1229{
1230 &quot;messageId&quot;:4,
1231 &quot;authorId&quot;:1,
1232 &quot;inResponseTo&quot;:2,
1233 &quot;senderLocation&quot;:[37.73,97.04],
1234 &quot;message&quot;:&quot; can't stand acast the network is horrible:(&quot;
1235},
1236{
1237 &quot;messageId&quot;:6,
1238 &quot;authorId&quot;:2,
1239 &quot;inResponseTo&quot;:1,
1240 &quot;senderLocation&quot;:[31.5,75.56],
1241 &quot;message&quot;:&quot; like product-z its platform is mind-blowing&quot;
1242}
1243{
1244 &quot;messageId&quot;:8,
1245 &quot;authorId&quot;:1,
1246 &quot;inResponseTo&quot;:11,
1247 &quot;senderLocation&quot;:[40.33,80.87],
1248 &quot;message&quot;:&quot; like ccast the 3G is awesome:)&quot;
1249},
1250{
1251 &quot;messageId&quot;:10,
1252 &quot;authorId&quot;:1,
1253 &quot;inResponseTo&quot;:12,
1254 &quot;senderLocation&quot;:[42.5,70.01],
1255 &quot;message&quot;:&quot; can't stand product-w the touch-screen is terrible&quot;
1256},
1257{
1258 &quot;messageId&quot;:11,
1259 &quot;authorId&quot;:1,
1260 &quot;inResponseTo&quot;:1,
1261 &quot;senderLocation&quot;:[38.97,77.49],
1262 &quot;message&quot;:&quot; can't stand acast its plan is terrible&quot;
1263} ]
1264</pre></div></div>
1265</div>
1266<div class="section">
1267<h2><a name="SELECT_Clause"></a><a name="Select_clauses" id="Select_clauses">SELECT Clause</a></h2>
1268<p>The <tt>SELECT</tt> clause always returns a collection value as its result (even if the result is empty or a singleton).</p>
1269<div class="section">
1270<h3><a name="Select_Element.2FValue.2FRaw"></a><a name="Select_element" id="Select_element">Select Element/Value/Raw</a></h3>
1271<p>The <tt>SELECT VALUE</tt> clause returns an array or multiset that contains the results of evaluating the <tt>VALUE</tt> expression, with one evaluation being performed per &#x201c;binding tuple&#x201d; (i.e., per <tt>FROM</tt> clause item) satisfying the statement&#x2019;s selection criteria. For historical reasons the query language also allows the keywords <tt>ELEMENT</tt> or <tt>RAW</tt> to be used in place of <tt>VALUE</tt> (not recommended).</p>
1272<p>If there is no FROM clause, the expression after <tt>VALUE</tt> is evaluated once with no binding tuples (except those inherited from an outer environment).</p>
1273<div class="section">
1274<div class="section">
1275<h5><a name="Example"></a>Example</h5>
1276
1277<div>
1278<div>
1279<pre class="source">SELECT VALUE 1;
1280</pre></div></div>
1281
1282<p>This query returns:</p>
1283
1284<div>
1285<div>
1286<pre class="source">[
1287 1
1288]
1289</pre></div></div>
1290
1291<p>The following example shows a query that selects one user from the GleambookUsers collection.</p></div>
1292<div class="section">
1293<h5><a name="Example"></a>Example</h5>
1294
1295<div>
1296<div>
1297<pre class="source">SELECT VALUE user
1298FROM GleambookUsers user
1299WHERE user.id = 1;
1300</pre></div></div>
1301
1302<p>This query returns:</p>
1303
1304<div>
1305<div>
1306<pre class="source">[{
1307 &quot;userSince&quot;: &quot;2012-08-20T10:10:00.000Z&quot;,
1308 &quot;friendIds&quot;: [
1309 2,
1310 3,
1311 6,
1312 10
1313 ],
1314 &quot;gender&quot;: &quot;F&quot;,
1315 &quot;name&quot;: &quot;MargaritaStoddard&quot;,
1316 &quot;nickname&quot;: &quot;Mags&quot;,
1317 &quot;alias&quot;: &quot;Margarita&quot;,
1318 &quot;id&quot;: 1,
1319 &quot;employment&quot;: [
1320 {
1321 &quot;organizationName&quot;: &quot;Codetechno&quot;,
1322 &quot;start-date&quot;: &quot;2006-08-06&quot;
1323 },
1324 {
1325 &quot;end-date&quot;: &quot;2010-01-26&quot;,
1326 &quot;organizationName&quot;: &quot;geomedia&quot;,
1327 &quot;start-date&quot;: &quot;2010-06-17&quot;
1328 }
1329 ]
1330} ]
1331</pre></div></div>
1332</div></div></div>
1333<div class="section">
1334<h3><a name="SQL-style_SELECT"></a><a name="SQL_select" id="SQL_select">SQL-style SELECT</a></h3>
1335<p>The traditional SQL-style <tt>SELECT</tt> syntax is also supported in the query language. This syntax can also be reformulated in a <tt>SELECT VALUE</tt> based manner. (E.g., <tt>SELECT expA AS fldA, expB AS fldB</tt> is syntactic sugar for <tt>SELECT VALUE { 'fldA': expA, 'fldB': expB }</tt>.) Unlike in SQL, the result of a query does not preserve the order of expressions in the <tt>SELECT</tt> clause.</p>
1336<div class="section">
1337<div class="section">
1338<h5><a name="Example"></a>Example</h5>
1339
1340<div>
1341<div>
1342<pre class="source">SELECT user.alias user_alias, user.name user_name
1343FROM GleambookUsers user
1344WHERE user.id = 1;
1345</pre></div></div>
1346
1347<p>Returns:</p>
1348
1349<div>
1350<div>
1351<pre class="source">[ {
1352 &quot;user_name&quot;: &quot;MargaritaStoddard&quot;,
1353 &quot;user_alias&quot;: &quot;Margarita&quot;
1354} ]
1355</pre></div></div>
1356</div></div></div>
1357<div class="section">
1358<h3><a name="SELECT_.2A"></a><a name="Select_star" id="Select_star">SELECT *</a></h3>
1359<p><tt>SELECT *</tt> returns an object with a nested field for each input tuple. Each field has as its field name the name of a binding variable generated by either the <tt>FROM</tt> clause or <tt>GROUP BY</tt> clause in the current enclosing <tt>SELECT</tt> statement, and its field value is the value of that binding variable.</p>
1360<p>Note that the result of <tt>SELECT *</tt> is different from the result of query that selects all the fields of an object.</p>
1361<div class="section">
1362<div class="section">
1363<h5><a name="Example"></a>Example</h5>
1364
1365<div>
1366<div>
1367<pre class="source">SELECT *
1368FROM GleambookUsers user;
1369</pre></div></div>
1370
1371<p>Since <tt>user</tt> is the only binding variable generated in the <tt>FROM</tt> clause, this query returns:</p>
1372
1373<div>
1374<div>
1375<pre class="source">[ {
1376 &quot;user&quot;: {
1377 &quot;userSince&quot;: &quot;2012-08-20T10:10:00.000Z&quot;,
1378 &quot;friendIds&quot;: [
1379 2,
1380 3,
1381 6,
1382 10
1383 ],
1384 &quot;gender&quot;: &quot;F&quot;,
1385 &quot;name&quot;: &quot;MargaritaStoddard&quot;,
1386 &quot;nickname&quot;: &quot;Mags&quot;,
1387 &quot;alias&quot;: &quot;Margarita&quot;,
1388 &quot;id&quot;: 1,
1389 &quot;employment&quot;: [
1390 {
1391 &quot;organizationName&quot;: &quot;Codetechno&quot;,
1392 &quot;start-date&quot;: &quot;2006-08-06&quot;
1393 },
1394 {
1395 &quot;end-date&quot;: &quot;2010-01-26&quot;,
1396 &quot;organizationName&quot;: &quot;geomedia&quot;,
1397 &quot;start-date&quot;: &quot;2010-06-17&quot;
1398 }
1399 ]
1400 }
1401}, {
1402 &quot;user&quot;: {
1403 &quot;userSince&quot;: &quot;2011-01-22T10:10:00.000Z&quot;,
1404 &quot;friendIds&quot;: [
1405 1,
1406 4
1407 ],
1408 &quot;name&quot;: &quot;IsbelDull&quot;,
1409 &quot;nickname&quot;: &quot;Izzy&quot;,
1410 &quot;alias&quot;: &quot;Isbel&quot;,
1411 &quot;id&quot;: 2,
1412 &quot;employment&quot;: [
1413 {
1414 &quot;organizationName&quot;: &quot;Hexviafind&quot;,
1415 &quot;startDate&quot;: &quot;2010-04-27&quot;
1416 }
1417 ]
1418 }
1419}, {
1420 &quot;user&quot;: {
1421 &quot;userSince&quot;: &quot;2012-07-10T10:10:00.000Z&quot;,
1422 &quot;friendIds&quot;: [
1423 1,
1424 5,
1425 8,
1426 9
1427 ],
1428 &quot;name&quot;: &quot;EmoryUnk&quot;,
1429 &quot;alias&quot;: &quot;Emory&quot;,
1430 &quot;id&quot;: 3,
1431 &quot;employment&quot;: [
1432 {
1433 &quot;organizationName&quot;: &quot;geomedia&quot;,
1434 &quot;endDate&quot;: &quot;2010-01-26&quot;,
1435 &quot;startDate&quot;: &quot;2010-06-17&quot;
1436 }
1437 ]
1438 }
1439} ]
1440</pre></div></div>
1441</div>
1442<div class="section">
1443<h5><a name="Example"></a>Example</h5>
1444
1445<div>
1446<div>
1447<pre class="source">SELECT *
1448FROM GleambookUsers u, GleambookMessages m
1449WHERE m.authorId = u.id and u.id = 2;
1450</pre></div></div>
1451
1452<p>This query does an inner join that we will discuss in <a href="#Multiple_from_terms">multiple from terms</a>. Since both <tt>u</tt> and <tt>m</tt> are binding variables generated in the <tt>FROM</tt> clause, this query returns:</p>
1453
1454<div>
1455<div>
1456<pre class="source">[ {
1457 &quot;u&quot;: {
1458 &quot;userSince&quot;: &quot;2011-01-22T10:10:00&quot;,
1459 &quot;friendIds&quot;: [
1460 1,
1461 4
1462 ],
1463 &quot;name&quot;: &quot;IsbelDull&quot;,
1464 &quot;nickname&quot;: &quot;Izzy&quot;,
1465 &quot;alias&quot;: &quot;Isbel&quot;,
1466 &quot;id&quot;: 2,
1467 &quot;employment&quot;: [
1468 {
1469 &quot;organizationName&quot;: &quot;Hexviafind&quot;,
1470 &quot;startDate&quot;: &quot;2010-04-27&quot;
1471 }
1472 ]
1473 },
1474 &quot;m&quot;: {
1475 &quot;senderLocation&quot;: [
1476 31.5,
1477 75.56
1478 ],
1479 &quot;inResponseTo&quot;: 1,
1480 &quot;messageId&quot;: 6,
1481 &quot;authorId&quot;: 2,
1482 &quot;message&quot;: &quot; like product-z its platform is mind-blowing&quot;
1483 }
1484}, {
1485 &quot;u&quot;: {
1486 &quot;userSince&quot;: &quot;2011-01-22T10:10:00&quot;,
1487 &quot;friendIds&quot;: [
1488 1,
1489 4
1490 ],
1491 &quot;name&quot;: &quot;IsbelDull&quot;,
1492 &quot;nickname&quot;: &quot;Izzy&quot;,
1493 &quot;alias&quot;: &quot;Isbel&quot;,
1494 &quot;id&quot;: 2,
1495 &quot;employment&quot;: [
1496 {
1497 &quot;organizationName&quot;: &quot;Hexviafind&quot;,
1498 &quot;startDate&quot;: &quot;2010-04-27&quot;
1499 }
1500 ]
1501 },
1502 &quot;m&quot;: {
1503 &quot;senderLocation&quot;: [
1504 48.09,
1505 81.01
1506 ],
1507 &quot;inResponseTo&quot;: 4,
1508 &quot;messageId&quot;: 3,
1509 &quot;authorId&quot;: 2,
1510 &quot;message&quot;: &quot; like product-y the plan is amazing&quot;
1511 }
1512} ]
1513</pre></div></div>
1514</div></div></div>
1515<div class="section">
1516<h3><a name="SELECT_variable..2A"></a><a name="Select_variable_star" id="Select_variable_star">SELECT <i>variable</i>.*</a></h3>
1517<p>Whereas <tt>SELECT *</tt> returns all the fields bound to all the variables which are currently defined, the notation <tt>SELECT c.*</tt> returns all the fields of the object bound to variable <tt>c</tt>. The variable <tt>c</tt> must be bound to an object for this to work.</p>
1518<div class="section">
1519<div class="section">
1520<h5><a name="Example"></a>Example</h5>
1521
1522<div>
1523<div>
1524<pre class="source">SELECT user.*
1525FROM GleambookUsers user;
1526</pre></div></div>
1527
1528<p>Compare this query with the first example given under <a href="#Select_star">SELECT *</a>. This query returns all users from the <tt>GleambookUsers</tt> dataset, but the <tt>user</tt> variable name is omitted from the results:</p>
1529
1530<div>
1531<div>
1532<pre class="source">[
1533 {
1534 &quot;id&quot;: 1,
1535 &quot;alias&quot;: &quot;Margarita&quot;,
1536 &quot;name&quot;: &quot;MargaritaStoddard&quot;,
1537 &quot;nickname&quot;: &quot;Mags&quot;,
1538 &quot;userSince&quot;: &quot;2012-08-20T10:10:00&quot;,
1539 &quot;friendIds&quot;: [
1540 2,
1541 3,
1542 6,
1543 10
1544 ],
1545 &quot;employment&quot;: [
1546 {
1547 &quot;organizationName&quot;: &quot;Codetechno&quot;,
1548 &quot;start-date&quot;: &quot;2006-08-06&quot;
1549 },
1550 {
1551 &quot;organizationName&quot;: &quot;geomedia&quot;,
1552 &quot;start-date&quot;: &quot;2010-06-17&quot;,
1553 &quot;end-date&quot;: &quot;2010-01-26&quot;
1554 }
1555 ],
1556 &quot;gender&quot;: &quot;F&quot;
1557 },
1558 {
1559 &quot;id&quot;: 2,
1560 &quot;alias&quot;: &quot;Isbel&quot;,
1561 &quot;name&quot;: &quot;IsbelDull&quot;,
1562 &quot;nickname&quot;: &quot;Izzy&quot;,
1563 &quot;userSince&quot;: &quot;2011-01-22T10:10:00&quot;,
1564 &quot;friendIds&quot;: [
1565 1,
1566 4
1567 ],
1568 &quot;employment&quot;: [
1569 {
1570 &quot;organizationName&quot;: &quot;Hexviafind&quot;,
1571 &quot;startDate&quot;: &quot;2010-04-27&quot;
1572 }
1573 ]
1574 },
1575 {
1576 &quot;id&quot;: 3,
1577 &quot;alias&quot;: &quot;Emory&quot;,
1578 &quot;name&quot;: &quot;EmoryUnk&quot;,
1579 &quot;userSince&quot;: &quot;2012-07-10T10:10:00&quot;,
1580 &quot;friendIds&quot;: [
1581 1,
1582 5,
1583 8,
1584 9
1585 ],
1586 &quot;employment&quot;: [
1587 {
1588 &quot;organizationName&quot;: &quot;geomedia&quot;,
1589 &quot;startDate&quot;: &quot;2010-06-17&quot;,
1590 &quot;endDate&quot;: &quot;2010-01-26&quot;
1591 }
1592 ]
1593 }
1594]
1595</pre></div></div>
1596</div></div></div>
1597<div class="section">
1598<h3><a name="SELECT_DISTINCT"></a><a name="Select_distinct" id="Select_distinct">SELECT DISTINCT</a></h3>
1599<p>The <tt>DISTINCT</tt> keyword is used to eliminate duplicate items in results. The following example shows how it works.</p>
1600<div class="section">
1601<div class="section">
1602<h5><a name="Example"></a>Example</h5>
1603
1604<div>
1605<div>
1606<pre class="source">SELECT DISTINCT * FROM [1, 2, 2, 3] AS foo;
1607</pre></div></div>
1608
1609<p>This query returns:</p>
1610
1611<div>
1612<div>
1613<pre class="source">[ {
1614 &quot;foo&quot;: 1
1615}, {
1616 &quot;foo&quot;: 2
1617}, {
1618 &quot;foo&quot;: 3
1619} ]
1620</pre></div></div>
1621</div>
1622<div class="section">
1623<h5><a name="Example"></a>Example</h5>
1624
1625<div>
1626<div>
1627<pre class="source">SELECT DISTINCT VALUE foo FROM [1, 2, 2, 3] AS foo;
1628</pre></div></div>
1629
1630<p>This version of the query returns:</p>
1631
1632<div>
1633<div>
1634<pre class="source">[ 1
1635, 2
1636, 3
1637 ]
1638</pre></div></div>
1639</div></div></div>
1640<div class="section">
1641<h3><a name="Unnamed_Projections"></a><a name="Unnamed_projections" id="Unnamed_projections">Unnamed Projections</a></h3>
1642<p>Similar to standard SQL, the query language supports unnamed projections (a.k.a, unnamed <tt>SELECT</tt> clause items), for which names are generated. Name generation has three cases:</p>
1643<ul>
1644
1645<li>If a projection expression is a variable reference expression, its generated name is the name of the variable.</li>
1646<li>If a projection expression is a field access expression, its generated name is the last identifier in the expression.</li>
1647<li>For all other cases, the query processor will generate a unique name.</li>
1648</ul>
1649<div class="section">
1650<div class="section">
1651<h5><a name="Example"></a>Example</h5>
1652
1653<div>
1654<div>
1655<pre class="source">SELECT substr(user.name, 10), user.alias
1656FROM GleambookUsers user
1657WHERE user.id = 1;
1658</pre></div></div>
1659
1660<p>This query outputs:</p>
1661
1662<div>
1663<div>
1664<pre class="source">[ {
1665 &quot;alias&quot;: &quot;Margarita&quot;,
1666 &quot;$1&quot;: &quot;Stoddard&quot;
1667} ]
1668</pre></div></div>
1669
1670<p>In the result, <tt>$1</tt> is the generated name for <tt>substr(user.name, 1)</tt>, while <tt>alias</tt> is the generated name for <tt>user.alias</tt>.</p></div></div></div>
1671<div class="section">
1672<h3><a name="Abbreviated_Field_Access_Expressions"></a><a name="Abbreviated_field_access_expressions" id="Abbreviated_field_access_expressions">Abbreviated Field Access Expressions</a></h3>
1673<p>As in standard SQL, field access expressions can be abbreviated (not recommended!) when there is no ambiguity. In the next example, the variable <tt>user</tt> is the only possible variable reference for fields <tt>id</tt>, <tt>name</tt> and <tt>alias</tt> and thus could be omitted in the query. More information on abbbreviated field access can be found in the appendix section on Variable Resolution.</p>
1674<div class="section">
1675<div class="section">
1676<h5><a name="Example"></a>Example</h5>
1677
1678<div>
1679<div>
1680<pre class="source">SELECT substr(name, 10) AS lname, alias
1681FROM GleambookUsers user
1682WHERE id = 1;
1683</pre></div></div>
1684
1685<p>Outputs:</p>
1686
1687<div>
1688<div>
1689<pre class="source">[ {
1690 &quot;lname&quot;: &quot;Stoddard&quot;,
1691 &quot;alias&quot;: &quot;Margarita&quot;
1692} ]
1693</pre></div></div>
1694</div></div></div></div>
1695<div class="section">
1696<h2><a name="UNNEST_Clause"></a><a name="Unnest_clauses" id="Unnest_clauses">UNNEST Clause</a></h2>
1697<p>For each of its input tuples, the <tt>UNNEST</tt> clause flattens a collection-valued expression into individual items, producing multiple tuples, each of which is one of the expression&#x2019;s original input tuples augmented with a flattened item from its collection.</p>
1698<div class="section">
1699<h3><a name="Inner_UNNEST"></a><a name="Inner_unnests" id="Inner_unnests">Inner UNNEST</a></h3>
1700<p>The following example is a query that retrieves the names of the organizations that a selected user has worked for. It uses the <tt>UNNEST</tt> clause to unnest the nested collection <tt>employment</tt> in the user&#x2019;s object.</p>
1701<div class="section">
1702<div class="section">
1703<h5><a name="Example"></a>Example</h5>
1704
1705<div>
1706<div>
1707<pre class="source">SELECT u.id AS userId, e.organizationName AS orgName
1708FROM GleambookUsers u
1709UNNEST u.employment e
1710WHERE u.id = 1;
1711</pre></div></div>
1712
1713<p>This query returns:</p>
1714
1715<div>
1716<div>
1717<pre class="source">[ {
1718 &quot;orgName&quot;: &quot;Codetechno&quot;,
1719 &quot;userId&quot;: 1
1720}, {
1721 &quot;orgName&quot;: &quot;geomedia&quot;,
1722 &quot;userId&quot;: 1
1723} ]
1724</pre></div></div>
1725
1726<p>Note that <tt>UNNEST</tt> has SQL&#x2019;s inner join semantics &#x2014; that is, if a user has no employment history, no tuple corresponding to that user will be emitted in the result.</p></div></div></div>
1727<div class="section">
1728<h3><a name="Left_Outer_UNNEST"></a><a name="Left_outer_unnests" id="Left_outer_unnests">Left Outer UNNEST</a></h3>
1729<p>As an alternative, the <tt>LEFT OUTER UNNEST</tt> clause offers SQL&#x2019;s left outer join semantics. For example, no collection-valued field named <tt>hobbies</tt> exists in the object for the user whose id is 1, but the following query&#x2019;s result still includes user 1.</p>
1730<div class="section">
1731<div class="section">
1732<h5><a name="Example"></a>Example</h5>
1733
1734<div>
1735<div>
1736<pre class="source">SELECT u.id AS userId, h.hobbyName AS hobby
1737FROM GleambookUsers u
1738LEFT OUTER UNNEST u.hobbies h
1739WHERE u.id = 1;
1740</pre></div></div>
1741
1742<p>Returns:</p>
1743
1744<div>
1745<div>
1746<pre class="source">[ {
1747 &quot;userId&quot;: 1
1748} ]
1749</pre></div></div>
1750
1751<p>Note that if <tt>u.hobbies</tt> is an empty collection or leads to a <tt>MISSING</tt> (as above) or <tt>NULL</tt> value for a given input tuple, there is no corresponding binding value for variable <tt>h</tt> for an input tuple. A <tt>MISSING</tt> value will be generated for <tt>h</tt> so that the input tuple can still be propagated.</p></div></div></div>
1752<div class="section">
1753<h3><a name="Expressing_Joins_Using_UNNEST"></a><a name="Expressing_joins_using_unnests" id="Expressing_joins_using_unnests">Expressing Joins Using UNNEST</a></h3>
1754<p>The <tt>UNNEST</tt> clause is similar to SQL&#x2019;s <tt>JOIN</tt> clause except that it allows its right argument to be correlated to its left argument, as in the examples above &#x2014; i.e., think &#x201c;correlated cross-product&#x201d;. The next example shows this via a query that joins two data sets, GleambookUsers and GleambookMessages, returning user/message pairs. The results contain one object per pair, with result objects containing the user&#x2019;s name and an entire message. The query can be thought of as saying &#x201c;for each Gleambook user, unnest the <tt>GleambookMessages</tt> collection and filter the output with the condition <tt>message.authorId = user.id</tt>&#x201d;.</p>
1755<div class="section">
1756<div class="section">
1757<h5><a name="Example"></a>Example</h5>
1758
1759<div>
1760<div>
1761<pre class="source">SELECT u.name AS uname, m.message AS message
1762FROM GleambookUsers u
1763UNNEST GleambookMessages m
1764WHERE m.authorId = u.id;
1765</pre></div></div>
1766
1767<p>This returns:</p>
1768
1769<div>
1770<div>
1771<pre class="source">[ {
1772 &quot;uname&quot;: &quot;MargaritaStoddard&quot;,
1773 &quot;message&quot;: &quot; can't stand acast its plan is terrible&quot;
1774}, {
1775 &quot;uname&quot;: &quot;MargaritaStoddard&quot;,
1776 &quot;message&quot;: &quot; dislike x-phone its touch-screen is horrible&quot;
1777}, {
1778 &quot;uname&quot;: &quot;MargaritaStoddard&quot;,
1779 &quot;message&quot;: &quot; can't stand acast the network is horrible:(&quot;
1780}, {
1781 &quot;uname&quot;: &quot;MargaritaStoddard&quot;,
1782 &quot;message&quot;: &quot; like ccast the 3G is awesome:)&quot;
1783}, {
1784 &quot;uname&quot;: &quot;MargaritaStoddard&quot;,
1785 &quot;message&quot;: &quot; can't stand product-w the touch-screen is terrible&quot;
1786}, {
1787 &quot;uname&quot;: &quot;IsbelDull&quot;,
1788 &quot;message&quot;: &quot; like product-z its platform is mind-blowing&quot;
1789}, {
1790 &quot;uname&quot;: &quot;IsbelDull&quot;,
1791 &quot;message&quot;: &quot; like product-y the plan is amazing&quot;
1792} ]
1793</pre></div></div>
1794
1795<p>Similarly, the above query can also be expressed as the <tt>UNNEST</tt>ing of a correlated subquery:</p></div>
1796<div class="section">
1797<h5><a name="Example"></a>Example</h5>
1798
1799<div>
1800<div>
1801<pre class="source">SELECT u.name AS uname, m.message AS message
1802FROM GleambookUsers u
1803UNNEST (
1804 SELECT VALUE msg
1805 FROM GleambookMessages msg
1806 WHERE msg.authorId = u.id
1807) AS m;
1808</pre></div></div>
1809</div></div></div></div>
1810<div class="section">
1811<h2><a name="FROM_clauses"></a><a name="From_clauses" id="From_clauses">FROM clauses</a></h2>
1812<p>A <tt>FROM</tt> clause is used for enumerating (i.e., conceptually iterating over) the contents of collections, as in SQL.</p>
1813<div class="section">
1814<h3><a name="Binding_expressions" id="Binding_expressions">Binding expressions</a></h3>
1815<p>In addition to stored collections, a <tt>FROM</tt> clause can iterate over any intermediate collection returned by a valid query expression. In the tuple stream generated by a <tt>FROM</tt> clause, the ordering of the input tuples are not guaranteed to be preserved.</p>
1816<div class="section">
1817<div class="section">
1818<h5><a name="Example"></a>Example</h5>
1819
1820<div>
1821<div>
1822<pre class="source">SELECT VALUE foo
1823FROM [1, 2, 2, 3] AS foo
1824WHERE foo &gt; 2;
1825</pre></div></div>
1826
1827<p>Returns:</p>
1828
1829<div>
1830<div>
1831<pre class="source">[
1832 3
1833]
1834</pre></div></div>
1835</div></div></div>
1836<div class="section">
1837<h3><a name="Multiple_FROM_Terms"></a><a name="Multiple_from_terms" id="Multiple_from_terms">Multiple FROM Terms</a></h3>
1838<p>The query language permits correlations among <tt>FROM</tt> terms. Specifically, a <tt>FROM</tt> binding expression can refer to variables defined to its left in the given <tt>FROM</tt> clause. Thus, the first unnesting example above could also be expressed as follows:</p>
1839<div class="section">
1840<div class="section">
1841<h5><a name="Example"></a>Example</h5>
1842
1843<div>
1844<div>
1845<pre class="source">SELECT u.id AS userId, e.organizationName AS orgName
1846FROM GleambookUsers u, u.employment e
1847WHERE u.id = 1;
1848</pre></div></div>
1849</div></div></div>
1850<div class="section">
1851<h3><a name="Expressing_Joins_Using_FROM_Terms"></a><a name="Expressing_joins_using_from_terms" id="Expressing_joins_using_from_terms">Expressing Joins Using FROM Terms</a></h3>
1852<p>Similarly, the join intentions of the other <tt>UNNEST</tt>-based join examples above could be expressed as:</p>
1853<div class="section">
1854<div class="section">
1855<h5><a name="Example"></a>Example</h5>
1856
1857<div>
1858<div>
1859<pre class="source">SELECT u.name AS uname, m.message AS message
1860FROM GleambookUsers u, GleambookMessages m
1861WHERE m.authorId = u.id;
1862</pre></div></div>
1863</div>
1864<div class="section">
1865<h5><a name="Example"></a>Example</h5>
1866
1867<div>
1868<div>
1869<pre class="source">SELECT u.name AS uname, m.message AS message
1870FROM GleambookUsers u,
1871 (
1872 SELECT VALUE msg
1873 FROM GleambookMessages msg
1874 WHERE msg.authorId = u.id
1875 ) AS m;
1876</pre></div></div>
1877
1878<p>Note that the first alternative is one of the SQL-92 approaches to expressing a join.</p></div></div></div>
1879<div class="section">
1880<h3><a name="Implicit_Binding_Variables"></a><a name="Implicit_binding_variables" id="Implicit_binding_variables">Implicit Binding Variables</a></h3>
1881<p>Similar to standard SQL, the query language supports implicit <tt>FROM</tt> binding variables (i.e., aliases), for which a binding variable is generated. Variable generation falls into three cases:</p>
1882<ul>
1883
1884<li>If the binding expression is a variable reference expression, the generated variable&#x2019;s name will be the name of the referenced variable itself.</li>
1885<li>If the binding expression is a field access expression (or a fully qualified name for a dataset), the generated variable&#x2019;s name will be the last identifier (or the dataset name) in the expression.</li>
1886<li>For all other cases, a compilation error will be raised.</li>
1887</ul>
1888<p>The next two examples show queries that do not provide binding variables in their <tt>FROM</tt> clauses.</p>
1889<div class="section">
1890<div class="section">
1891<h5><a name="Example"></a>Example</h5>
1892
1893<div>
1894<div>
1895<pre class="source">SELECT GleambookUsers.name, GleambookMessages.message
1896FROM GleambookUsers, GleambookMessages
1897WHERE GleambookMessages.authorId = GleambookUsers.id;
1898</pre></div></div>
1899
1900<p>Returns:</p>
1901
1902<div>
1903<div>
1904<pre class="source">[ {
1905 &quot;name&quot;: &quot;MargaritaStoddard&quot;,
1906 &quot;message&quot;: &quot; like ccast the 3G is awesome:)&quot;
1907}, {
1908 &quot;name&quot;: &quot;MargaritaStoddard&quot;,
1909 &quot;message&quot;: &quot; can't stand product-w the touch-screen is terrible&quot;
1910}, {
1911 &quot;name&quot;: &quot;MargaritaStoddard&quot;,
1912 &quot;message&quot;: &quot; can't stand acast its plan is terrible&quot;
1913}, {
1914 &quot;name&quot;: &quot;MargaritaStoddard&quot;,
1915 &quot;message&quot;: &quot; dislike x-phone its touch-screen is horrible&quot;
1916}, {
1917 &quot;name&quot;: &quot;MargaritaStoddard&quot;,
1918 &quot;message&quot;: &quot; can't stand acast the network is horrible:(&quot;
1919}, {
1920 &quot;name&quot;: &quot;IsbelDull&quot;,
1921 &quot;message&quot;: &quot; like product-y the plan is amazing&quot;
1922}, {
1923 &quot;name&quot;: &quot;IsbelDull&quot;,
1924 &quot;message&quot;: &quot; like product-z its platform is mind-blowing&quot;
1925} ]
1926</pre></div></div>
1927</div>
1928<div class="section">
1929<h5><a name="Example"></a>Example</h5>
1930
1931<div>
1932<div>
1933<pre class="source">SELECT GleambookUsers.name, GleambookMessages.message
1934FROM GleambookUsers,
1935 (
1936 SELECT VALUE GleambookMessages
1937 FROM GleambookMessages
1938 WHERE GleambookMessages.authorId = GleambookUsers.id
1939 );
1940</pre></div></div>
1941
1942<p>Returns:</p>
1943
1944<div>
1945<div>
1946<pre class="source">Error: &quot;Syntax error: Need an alias for the enclosed expression:\n(select element GleambookMessages\n from GleambookMessages as GleambookMessages\n where (GleambookMessages.authorId = GleambookUsers.id)\n )&quot;,
1947 &quot;query_from_user&quot;: &quot;use TinySocial;\n\nSELECT GleambookUsers.name, GleambookMessages.message\n FROM GleambookUsers,\n (\n SELECT VALUE GleambookMessages\n FROM GleambookMessages\n WHERE GleambookMessages.authorId = GleambookUsers.id\n );&quot;
1948</pre></div></div>
1949
1950<p>More information on implicit binding variables can be found in the appendix section on Variable Resolution.</p></div></div></div></div>
1951<div class="section">
1952<h2><a name="JOIN_Clauses"></a><a name="Join_clauses" id="Join_clauses">JOIN Clauses</a></h2>
1953<p>The join clause in the query language supports both inner joins and left outer joins from standard SQL.</p>
1954<div class="section">
1955<h3><a name="Inner_joins" id="Inner_joins">Inner joins</a></h3>
1956<p>Using a <tt>JOIN</tt> clause, the inner join intent from the preceding examples can also be expressed as follows:</p>
1957<div class="section">
1958<div class="section">
1959<h5><a name="Example"></a>Example</h5>
1960
1961<div>
1962<div>
1963<pre class="source">SELECT u.name AS uname, m.message AS message
1964FROM GleambookUsers u JOIN GleambookMessages m ON m.authorId = u.id;
1965</pre></div></div>
1966</div></div></div>
1967<div class="section">
1968<h3><a name="Left_Outer_Joins"></a><a name="Left_outer_joins" id="Left_outer_joins">Left Outer Joins</a></h3>
1969<p>The query language supports SQL&#x2019;s notion of left outer join. The following query is an example:</p>
1970
1971<div>
1972<div>
1973<pre class="source">SELECT u.name AS uname, m.message AS message
1974FROM GleambookUsers u LEFT OUTER JOIN GleambookMessages m ON m.authorId = u.id;
1975</pre></div></div>
1976
1977<p>Returns:</p>
1978
1979<div>
1980<div>
1981<pre class="source">[ {
1982 &quot;uname&quot;: &quot;MargaritaStoddard&quot;,
1983 &quot;message&quot;: &quot; like ccast the 3G is awesome:)&quot;
1984}, {
1985 &quot;uname&quot;: &quot;MargaritaStoddard&quot;,
1986 &quot;message&quot;: &quot; can't stand product-w the touch-screen is terrible&quot;
1987}, {
1988 &quot;uname&quot;: &quot;MargaritaStoddard&quot;,
1989 &quot;message&quot;: &quot; can't stand acast its plan is terrible&quot;
1990}, {
1991 &quot;uname&quot;: &quot;MargaritaStoddard&quot;,
1992 &quot;message&quot;: &quot; dislike x-phone its touch-screen is horrible&quot;
1993}, {
1994 &quot;uname&quot;: &quot;MargaritaStoddard&quot;,
1995 &quot;message&quot;: &quot; can't stand acast the network is horrible:(&quot;
1996}, {
1997 &quot;uname&quot;: &quot;IsbelDull&quot;,
1998 &quot;message&quot;: &quot; like product-y the plan is amazing&quot;
1999}, {
2000 &quot;uname&quot;: &quot;IsbelDull&quot;,
2001 &quot;message&quot;: &quot; like product-z its platform is mind-blowing&quot;
2002}, {
2003 &quot;uname&quot;: &quot;EmoryUnk&quot;
2004} ]
2005</pre></div></div>
2006
2007<p>For non-matching left-side tuples, the query language produces <tt>MISSING</tt> values for the right-side binding variables; that is why the last object in the above result doesn&#x2019;t have a <tt>message</tt> field. Note that this is slightly different from standard SQL, which instead would fill in <tt>NULL</tt> values for the right-side fields. The reason for this difference is that, for non-matches in its join results, the query language views fields from the right-side as being &#x201c;not there&#x201d; (a.k.a. <tt>MISSING</tt>) instead of as being &#x201c;there but unknown&#x201d; (i.e., <tt>NULL</tt>).</p>
2008<p>The left-outer join query can also be expressed using <tt>LEFT OUTER UNNEST</tt>:</p>
2009
2010<div>
2011<div>
2012<pre class="source">SELECT u.name AS uname, m.message AS message
2013FROM GleambookUsers u
2014LEFT OUTER UNNEST (
2015 SELECT VALUE message
2016 FROM GleambookMessages message
2017 WHERE message.authorId = u.id
2018 ) m;
2019</pre></div></div>
2020
2021<p>In general, SQL-style join queries can also be expressed by <tt>UNNEST</tt> clauses and left outer join queries can be expressed by <tt>LEFT OUTER UNNESTs</tt>.</p></div>
2022<div class="section">
2023<h3><a name="Variable_scope_in_JOIN_clauses"></a><a name="Join_variable_scope" id="Join_variable_scope">Variable scope in JOIN clauses</a></h3>
2024<p>Variables defined by <tt>JOIN</tt> subclauses are not visible to other subclauses in the same <tt>FROM</tt> clause. This also applies to the <tt>FROM</tt> variable that starts the <tt>JOIN</tt> subclause.</p>
2025<div class="section">
2026<div class="section">
2027<h5><a name="Example"></a>Example</h5>
2028
2029<div>
2030<div>
2031<pre class="source">SELECT * FROM GleambookUsers u
2032JOIN (SELECT VALUE m
2033 FROM GleambookMessages m
2034 WHERE m.authorId = u.id) m
2035ON u.id = m.authorId;
2036</pre></div></div>
2037
2038<p>The variable <tt>u</tt> defined by the <tt>FROM</tt> clause is not visible inside the <tt>JOIN</tt> subclause, so this query returns no results.</p></div></div></div></div>
2039<div class="section">
2040<h2><a name="GROUP_BY_Clauses"></a><a name="Group_By_clauses" id="Group_By_clauses">GROUP BY Clauses</a></h2>
2041<p>The <tt>GROUP BY</tt> clause generalizes standard SQL&#x2019;s grouping and aggregation semantics, but it also retains backward compatibility with the standard (relational) SQL <tt>GROUP BY</tt> and aggregation features.</p>
2042<div class="section">
2043<h3><a name="Group_variables" id="Group_variables">Group variables</a></h3>
2044<p>In a <tt>GROUP BY</tt> clause, in addition to the binding variable(s) defined for the grouping key(s), the query language allows a user to define a <i>group variable</i> by using the clause&#x2019;s <tt>GROUP AS</tt> extension to denote the resulting group. After grouping, then, the query&#x2019;s in-scope variables include the grouping key&#x2019;s binding variables as well as this group variable which will be bound to one collection value for each group. This per-group collection (i.e., multiset) value will be a set of nested objects in which each field of the object is the result of a renamed variable defined in parentheses following the group variable&#x2019;s name. The <tt>GROUP AS</tt> syntax is as follows:</p>
2045
2046<div>
2047<div>
2048<pre class="source">&lt;GROUP&gt; &lt;AS&gt; Variable (&quot;(&quot; VariableReference &lt;AS&gt; Identifier (&quot;,&quot; VariableReference &lt;AS&gt; Identifier )* &quot;)&quot;)?
2049</pre></div></div>
2050
2051<div class="section">
2052<div class="section">
2053<h5><a name="Example"></a>Example</h5>
2054
2055<div>
2056<div>
2057<pre class="source">SELECT *
2058FROM GleambookMessages message
2059GROUP BY message.authorId AS uid GROUP AS msgs(message AS msg);
2060</pre></div></div>
2061
2062<p>This first example query returns:</p>
2063
2064<div>
2065<div>
2066<pre class="source">[ {
2067 &quot;msgs&quot;: [
2068 {
2069 &quot;msg&quot;: {
2070 &quot;senderLocation&quot;: [
2071 38.97,
2072 77.49
2073 ],
2074 &quot;inResponseTo&quot;: 1,
2075 &quot;messageId&quot;: 11,
2076 &quot;authorId&quot;: 1,
2077 &quot;message&quot;: &quot; can't stand acast its plan is terrible&quot;
2078 }
2079 },
2080 {
2081 &quot;msg&quot;: {
2082 &quot;senderLocation&quot;: [
2083 41.66,
2084 80.87
2085 ],
2086 &quot;inResponseTo&quot;: 4,
2087 &quot;messageId&quot;: 2,
2088 &quot;authorId&quot;: 1,
2089 &quot;message&quot;: &quot; dislike x-phone its touch-screen is horrible&quot;
2090 }
2091 },
2092 {
2093 &quot;msg&quot;: {
2094 &quot;senderLocation&quot;: [
2095 37.73,
2096 97.04
2097 ],
2098 &quot;inResponseTo&quot;: 2,
2099 &quot;messageId&quot;: 4,
2100 &quot;authorId&quot;: 1,
2101 &quot;message&quot;: &quot; can't stand acast the network is horrible:(&quot;
2102 }
2103 },
2104 {
2105 &quot;msg&quot;: {
2106 &quot;senderLocation&quot;: [
2107 40.33,
2108 80.87
2109 ],
2110 &quot;inResponseTo&quot;: 11,
2111 &quot;messageId&quot;: 8,
2112 &quot;authorId&quot;: 1,
2113 &quot;message&quot;: &quot; like ccast the 3G is awesome:)&quot;
2114 }
2115 },
2116 {
2117 &quot;msg&quot;: {
2118 &quot;senderLocation&quot;: [
2119 42.5,
2120 70.01
2121 ],
2122 &quot;inResponseTo&quot;: 12,
2123 &quot;messageId&quot;: 10,
2124 &quot;authorId&quot;: 1,
2125 &quot;message&quot;: &quot; can't stand product-w the touch-screen is terrible&quot;
2126 }
2127 }
2128 ],
2129 &quot;uid&quot;: 1
2130}, {
2131 &quot;msgs&quot;: [
2132 {
2133 &quot;msg&quot;: {
2134 &quot;senderLocation&quot;: [
2135 31.5,
2136 75.56
2137 ],
2138 &quot;inResponseTo&quot;: 1,
2139 &quot;messageId&quot;: 6,
2140 &quot;authorId&quot;: 2,
2141 &quot;message&quot;: &quot; like product-z its platform is mind-blowing&quot;
2142 }
2143 },
2144 {
2145 &quot;msg&quot;: {
2146 &quot;senderLocation&quot;: [
2147 48.09,
2148 81.01
2149 ],
2150 &quot;inResponseTo&quot;: 4,
2151 &quot;messageId&quot;: 3,
2152 &quot;authorId&quot;: 2,
2153 &quot;message&quot;: &quot; like product-y the plan is amazing&quot;
2154 }
2155 }
2156 ],
2157 &quot;uid&quot;: 2
2158} ]
2159</pre></div></div>
2160
2161<p>As we can see from the above query result, each group in the example query&#x2019;s output has an associated group variable value called <tt>msgs</tt> that appears in the <tt>SELECT *</tt>&#x2019;s result. This variable contains a collection of objects associated with the group; each of the group&#x2019;s <tt>message</tt> values appears in the <tt>msg</tt> field of the objects in the <tt>msgs</tt> collection.</p>
2162<p>The group variable in the query language makes more complex, composable, nested subqueries over a group possible, which is important given the language&#x2019;s more complex data model (relative to SQL). As a simple example of this, as we really just want the messages associated with each user, we might wish to avoid the &#x201c;extra wrapping&#x201d; of each message as the <tt>msg</tt> field of an object. (That wrapping is useful in more complex cases, but is essentially just in the way here.) We can use a subquery in the <tt>SELECT</tt> clause to tunnel through the extra nesting and produce the desired result.</p></div>
2163<div class="section">
2164<h5><a name="Example"></a>Example</h5>
2165
2166<div>
2167<div>
2168<pre class="source">SELECT uid, (SELECT VALUE g.msg FROM g) AS msgs
2169FROM GleambookMessages gbm
2170GROUP BY gbm.authorId AS uid
2171GROUP AS g(gbm as msg);
2172</pre></div></div>
2173
2174<p>This variant of the example query returns:</p>
2175
2176<div>
2177<div>
2178<pre class="source"> [ {
2179 &quot;msgs&quot;: [
2180 {
2181 &quot;senderLocation&quot;: [
2182 38.97,
2183 77.49
2184 ],
2185 &quot;inResponseTo&quot;: 1,
2186 &quot;messageId&quot;: 11,
2187 &quot;authorId&quot;: 1,
2188 &quot;message&quot;: &quot; can't stand acast its plan is terrible&quot;
2189 },
2190 {
2191 &quot;senderLocation&quot;: [
2192 41.66,
2193 80.87
2194 ],
2195 &quot;inResponseTo&quot;: 4,
2196 &quot;messageId&quot;: 2,
2197 &quot;authorId&quot;: 1,
2198 &quot;message&quot;: &quot; dislike x-phone its touch-screen is horrible&quot;
2199 },
2200 {
2201 &quot;senderLocation&quot;: [
2202 37.73,
2203 97.04
2204 ],
2205 &quot;inResponseTo&quot;: 2,
2206 &quot;messageId&quot;: 4,
2207 &quot;authorId&quot;: 1,
2208 &quot;message&quot;: &quot; can't stand acast the network is horrible:(&quot;
2209 },
2210 {
2211 &quot;senderLocation&quot;: [
2212 40.33,
2213 80.87
2214 ],
2215 &quot;inResponseTo&quot;: 11,
2216 &quot;messageId&quot;: 8,
2217 &quot;authorId&quot;: 1,
2218 &quot;message&quot;: &quot; like ccast the 3G is awesome:)&quot;
2219 },
2220 {
2221 &quot;senderLocation&quot;: [
2222 42.5,
2223 70.01
2224 ],
2225 &quot;inResponseTo&quot;: 12,
2226 &quot;messageId&quot;: 10,
2227 &quot;authorId&quot;: 1,
2228 &quot;message&quot;: &quot; can't stand product-w the touch-screen is terrible&quot;
2229 }
2230 ],
2231 &quot;uid&quot;: 1
2232 }, {
2233 &quot;msgs&quot;: [
2234 {
2235 &quot;senderLocation&quot;: [
2236 31.5,
2237 75.56
2238 ],
2239 &quot;inResponseTo&quot;: 1,
2240 &quot;messageId&quot;: 6,
2241 &quot;authorId&quot;: 2,
2242 &quot;message&quot;: &quot; like product-z its platform is mind-blowing&quot;
2243 },
2244 {
2245 &quot;senderLocation&quot;: [
2246 48.09,
2247 81.01
2248 ],
2249 &quot;inResponseTo&quot;: 4,
2250 &quot;messageId&quot;: 3,
2251 &quot;authorId&quot;: 2,
2252 &quot;message&quot;: &quot; like product-y the plan is amazing&quot;
2253 }
2254 ],
2255 &quot;uid&quot;: 2
2256 } ]
2257</pre></div></div>
2258
2259<p>The next example shows a more interesting case involving the use of a subquery in the <tt>SELECT</tt> list. Here the subquery further processes the groups. There is no renaming in the declaration of the group variable <tt>g</tt> such that <tt>g</tt> only has one field <tt>gbm</tt> which comes from the <tt>FROM</tt> clause.</p></div>
2260<div class="section">
2261<h5><a name="Example"></a>Example</h5>
2262
2263<div>
2264<div>
2265<pre class="source">SELECT uid,
2266 (SELECT VALUE g.gbm
2267 FROM g
2268 WHERE g.gbm.message LIKE '% like%'
2269 ORDER BY g.gbm.messageId
2270 LIMIT 2) AS msgs
2271FROM GleambookMessages gbm
2272GROUP BY gbm.authorId AS uid
2273GROUP AS g;
2274</pre></div></div>
2275
2276<p>This example query returns:</p>
2277
2278<div>
2279<div>
2280<pre class="source">[ {
2281 &quot;msgs&quot;: [
2282 {
2283 &quot;senderLocation&quot;: [
2284 40.33,
2285 80.87
2286 ],
2287 &quot;inResponseTo&quot;: 11,
2288 &quot;messageId&quot;: 8,
2289 &quot;authorId&quot;: 1,
2290 &quot;message&quot;: &quot; like ccast the 3G is awesome:)&quot;
2291 }
2292 ],
2293 &quot;uid&quot;: 1
2294}, {
2295 &quot;msgs&quot;: [
2296 {
2297 &quot;senderLocation&quot;: [
2298 48.09,
2299 81.01
2300 ],
2301 &quot;inResponseTo&quot;: 4,
2302 &quot;messageId&quot;: 3,
2303 &quot;authorId&quot;: 2,
2304 &quot;message&quot;: &quot; like product-y the plan is amazing&quot;
2305 },
2306 {
2307 &quot;senderLocation&quot;: [
2308 31.5,
2309 75.56
2310 ],
2311 &quot;inResponseTo&quot;: 1,
2312 &quot;messageId&quot;: 6,
2313 &quot;authorId&quot;: 2,
2314 &quot;message&quot;: &quot; like product-z its platform is mind-blowing&quot;
2315 }
2316 ],
2317 &quot;uid&quot;: 2
2318} ]
2319</pre></div></div>
2320</div></div></div>
2321<div class="section">
2322<h3><a name="Implicit_Grouping_Key_Variables"></a><a name="Implicit_group_key_variables" id="Implicit_group_key_variables">Implicit Grouping Key Variables</a></h3>
2323<p>In the query language syntax, providing named binding variables for <tt>GROUP BY</tt> key expressions is optional. If a grouping key is missing a user-provided binding variable, the underlying compiler will generate one. Automatic grouping key variable naming falls into three cases, much like the treatment of unnamed projections:</p>
2324<ul>
2325
2326<li>If the grouping key expression is a variable reference expression, the generated variable gets the same name as the referred variable;</li>
2327<li>If the grouping key expression is a field access expression, the generated variable gets the same name as the last identifier in the expression;</li>
2328<li>For all other cases, the compiler generates a unique variable (but the user query is unable to refer to this generated variable).</li>
2329</ul>
2330<p>The next example illustrates a query that doesn&#x2019;t provide binding variables for its grouping key expressions.</p>
2331<div class="section">
2332<div class="section">
2333<h5><a name="Example"></a>Example</h5>
2334
2335<div>
2336<div>
2337<pre class="source">SELECT authorId,
2338 (SELECT VALUE g.gbm
2339 FROM g
2340 WHERE g.gbm.message LIKE '% like%'
2341 ORDER BY g.gbm.messageId
2342 LIMIT 2) AS msgs
2343FROM GleambookMessages gbm
2344GROUP BY gbm.authorId
2345GROUP AS g;
2346</pre></div></div>
2347
2348<p>This query returns:</p>
2349
2350<div>
2351<div>
2352<pre class="source"> [ {
2353 &quot;msgs&quot;: [
2354 {
2355 &quot;senderLocation&quot;: [
2356 40.33,
2357 80.87
2358 ],
2359 &quot;inResponseTo&quot;: 11,
2360 &quot;messageId&quot;: 8,
2361 &quot;authorId&quot;: 1,
2362 &quot;message&quot;: &quot; like ccast the 3G is awesome:)&quot;
2363 }
2364 ],
2365 &quot;authorId&quot;: 1
2366}, {
2367 &quot;msgs&quot;: [
2368 {
2369 &quot;senderLocation&quot;: [
2370 48.09,
2371 81.01
2372 ],
2373 &quot;inResponseTo&quot;: 4,
2374 &quot;messageId&quot;: 3,
2375 &quot;authorId&quot;: 2,
2376 &quot;message&quot;: &quot; like product-y the plan is amazing&quot;
2377 },
2378 {
2379 &quot;senderLocation&quot;: [
2380 31.5,
2381 75.56
2382 ],
2383 &quot;inResponseTo&quot;: 1,
2384 &quot;messageId&quot;: 6,
2385 &quot;authorId&quot;: 2,
2386 &quot;message&quot;: &quot; like product-z its platform is mind-blowing&quot;
2387 }
2388 ],
2389 &quot;authorId&quot;: 2
2390} ]
2391</pre></div></div>
2392
2393<p>Based on the three variable generation rules, the generated variable for the grouping key expression <tt>message.authorId</tt> is <tt>authorId</tt> (which is how it is referred to in the example&#x2019;s <tt>SELECT</tt> clause).</p></div></div></div>
2394<div class="section">
2395<h3><a name="Implicit_Group_Variables"></a><a name="Implicit_group_variables" id="Implicit_group_variables">Implicit Group Variables</a></h3>
2396<p>The group variable itself is also optional in the <tt>GROUP BY</tt> syntax. If a user&#x2019;s query does not declare the name and structure of the group variable using <tt>GROUP AS</tt>, the query compiler will generate a unique group variable whose fields include all of the binding variables defined in the <tt>FROM</tt> clause of the current enclosing <tt>SELECT</tt> statement. In this case the user&#x2019;s query will not be able to refer to the generated group variable, but is able to call SQL-92 aggregation functions as in SQL-92.</p></div>
2397<div class="section">
2398<h3><a name="Aggregation_Functions"></a><a name="Aggregation_functions" id="Aggregation_functions">Aggregation Functions</a></h3>
2399<p>In the traditional SQL, which doesn&#x2019;t support nested data, grouping always also involves the use of aggregation to compute properties of the groups (for example, the average number of messages per user rather than the actual set of messages per user). Each aggregation function in the query language takes a collection (for example, the group of messages) as its input and produces a scalar value as its output. These aggregation functions, being truly functional in nature (unlike in SQL), can be used anywhere in a query where an expression is allowed. The following table catalogs the built-in aggregation functions of the query language and also indicates how each one handles <tt>NULL</tt>/<tt>MISSING</tt> values in the input collection or a completely empty input collection:</p>
2400<table border="0" class="table table-striped">
2401<thead>
2402
2403<tr class="a">
2404<th> Function </th>
2405<th> NULL </th>
2406<th> MISSING </th>
2407<th> Empty Collection </th></tr>
2408</thead><tbody>
2409
2410<tr class="b">
2411<td> STRICT_COUNT </td>
2412<td> counted </td>
2413<td> counted </td>
2414<td> 0 </td></tr>
2415<tr class="a">
2416<td> STRICT_SUM </td>
2417<td> returns NULL </td>
2418<td> returns NULL </td>
2419<td> returns NULL </td></tr>
2420<tr class="b">
2421<td> STRICT_MAX </td>
2422<td> returns NULL </td>
2423<td> returns NULL </td>
2424<td> returns NULL </td></tr>
2425<tr class="a">
2426<td> STRICT_MIN </td>
2427<td> returns NULL </td>
2428<td> returns NULL </td>
2429<td> returns NULL </td></tr>
2430<tr class="b">
2431<td> STRICT_AVG </td>
2432<td> returns NULL </td>
2433<td> returns NULL </td>
2434<td> returns NULL </td></tr>
2435<tr class="a">
2436<td> ARRAY_COUNT </td>
2437<td> not counted </td>
2438<td> not counted </td>
2439<td> 0 </td></tr>
2440<tr class="b">
2441<td> ARRAY_SUM </td>
2442<td> ignores NULL </td>
2443<td> ignores NULL </td>
2444<td> returns NULL </td></tr>
2445<tr class="a">
2446<td> ARRAY_MAX </td>
2447<td> ignores NULL </td>
2448<td> ignores NULL </td>
2449<td> returns NULL </td></tr>
2450<tr class="b">
2451<td> ARRAY_MIN </td>
2452<td> ignores NULL </td>
2453<td> ignores NULL </td>
2454<td> returns NULL </td></tr>
2455<tr class="a">
2456<td> ARRAY_AVG </td>
2457<td> ignores NULL </td>
2458<td> ignores NULL </td>
2459<td> returns NULL </td></tr>
2460</tbody>
2461</table>
2462<p>Notice that the query language has twice as many functions listed above as there are aggregate functions in SQL-92. This is because the language offers two versions of each &#x2013; one that handles <tt>UNKNOWN</tt> values in a semantically strict fashion, where unknown values in the input result in unknown values in the output &#x2013; and one that handles them in the ad hoc &#x201c;just ignore the unknown values&#x201d; fashion that the SQL standard chose to adopt.</p>
2463<div class="section">
2464<div class="section">
2465<h5><a name="Example"></a>Example</h5>
2466
2467<div>
2468<div>
2469<pre class="source">ARRAY_AVG(
2470 (
2471 SELECT VALUE ARRAY_COUNT(friendIds) FROM GleambookUsers
2472 )
2473);
2474</pre></div></div>
2475
2476<p>This example returns:</p>
2477
2478<div>
2479<div>
2480<pre class="source">3.3333333333333335
2481</pre></div></div>
2482</div>
2483<div class="section">
2484<h5><a name="Example"></a>Example</h5>
2485
2486<div>
2487<div>
2488<pre class="source">SELECT uid AS uid, ARRAY_COUNT(grp) AS msgCnt
2489FROM GleambookMessages message
2490GROUP BY message.authorId AS uid
2491GROUP AS grp(message AS msg);
2492</pre></div></div>
2493
2494<p>This query returns:</p>
2495
2496<div>
2497<div>
2498<pre class="source">[ {
2499 &quot;uid&quot;: 1,
2500 &quot;msgCnt&quot;: 5
2501}, {
2502 &quot;uid&quot;: 2,
2503 &quot;msgCnt&quot;: 2
2504} ]
2505</pre></div></div>
2506
2507<p>Notice how the query forms groups where each group involves a message author and their messages. (SQL cannot do this because the grouped intermediate result is non-1NF in nature.) The query then uses the collection aggregate function ARRAY_COUNT to get the cardinality of each group of messages.</p>
2508<p>Each aggregation function in the query language supports DISTINCT modifier that removes duplicate values from the input collection.</p></div>
2509<div class="section">
2510<h5><a name="Example"></a>Example</h5>
2511
2512<div>
2513<div>
2514<pre class="source">ARRAY_SUM(DISTINCT [1, 1, 2, 2, 3])
2515</pre></div></div>
2516
2517<p>This query returns:</p>
2518
2519<div>
2520<div>
2521<pre class="source">6
2522</pre></div></div>
2523</div></div></div>
2524<div class="section">
2525<h3><a name="SQL-92_Aggregation_Functions"></a><a name="SQL-92_aggregation_functions" id="SQL-92_aggregation_functions">SQL-92 Aggregation Functions</a></h3>
2526<p>For compatibility with the traditional SQL aggregation functions, the query language also offers SQL-92&#x2019;s aggregation function symbols (<tt>COUNT</tt>, <tt>SUM</tt>, <tt>MAX</tt>, <tt>MIN</tt>, and <tt>AVG</tt>) as supported syntactic sugar. The query compiler rewrites queries that utilize these function symbols into queries that only use the collection aggregate functions of the query language. The following example uses the SQL-92 syntax approach to compute a result that is identical to that of the more explicit example above:</p>
2527<div class="section">
2528<div class="section">
2529<h5><a name="Example"></a>Example</h5>
2530
2531<div>
2532<div>
2533<pre class="source">SELECT uid, COUNT(*) AS msgCnt
2534FROM GleambookMessages msg
2535GROUP BY msg.authorId AS uid;
2536</pre></div></div>
2537
2538<p>It is important to realize that <tt>COUNT</tt> is actually <b>not</b> a built-in aggregation function. Rather, the <tt>COUNT</tt> query above is using a special &#x201c;sugared&#x201d; function symbol that the query compiler will rewrite as follows:</p>
2539
2540<div>
2541<div>
2542<pre class="source">SELECT uid AS uid, ARRAY_COUNT( (SELECT VALUE 1 FROM `$1` as g) ) AS msgCnt
2543FROM GleambookMessages msg
2544GROUP BY msg.authorId AS uid
2545GROUP AS `$1`(msg AS msg);
2546</pre></div></div>
2547
2548<p>The same sort of rewritings apply to the function symbols <tt>SUM</tt>, <tt>MAX</tt>, <tt>MIN</tt>, and <tt>AVG</tt>. In contrast to the collection aggregate functions of the query language, these special SQL-92 function symbols can only be used in the same way they are in standard SQL (i.e., with the same restrictions).</p>
2549<p>DISTINCT modifier is also supported for these aggregate functions.</p></div></div></div>
2550<div class="section">
2551<h3><a name="SQL-92_Compliant_GROUP_BY_Aggregations"></a><a name="SQL-92_compliant_gby" id="SQL-92_compliant_gby">SQL-92 Compliant GROUP BY Aggregations</a></h3>
2552<p>The query language provides full support for SQL-92 <tt>GROUP BY</tt> aggregation queries. The following query is such an example:</p>
2553<div class="section">
2554<div class="section">
2555<h5><a name="Example"></a>Example</h5>
2556
2557<div>
2558<div>
2559<pre class="source">SELECT msg.authorId, COUNT(*)
2560FROM GleambookMessages msg
2561GROUP BY msg.authorId;
2562</pre></div></div>
2563
2564<p>This query outputs:</p>
2565
2566<div>
2567<div>
2568<pre class="source">[ {
2569 &quot;authorId&quot;: 1,
2570 &quot;$1&quot;: 5
2571}, {
2572 &quot;authorId&quot;: 2,
2573 &quot;$1&quot;: 2
2574} ]
2575</pre></div></div>
2576
2577<p>In principle, a <tt>msg</tt> reference in the query&#x2019;s <tt>SELECT</tt> clause would be &#x201c;sugarized&#x201d; as a collection (as described in <a href="#Implicit_group_variables">Implicit Group Variables</a>). However, since the SELECT expression <tt>msg.authorId</tt> is syntactically identical to a GROUP BY key expression, it will be internally replaced by the generated group key variable. The following is the equivalent rewritten query that will be generated by the compiler for the query above:</p>
2578
2579<div>
2580<div>
2581<pre class="source">SELECT authorId AS authorId, ARRAY_COUNT( (SELECT g.msg FROM `$1` AS g) )
2582FROM GleambookMessages msg
2583GROUP BY msg.authorId AS authorId
2584GROUP AS `$1`(msg AS msg);
2585</pre></div></div>
2586</div></div></div>
2587<div class="section">
2588<h3><a name="Column_Aliases"></a><a name="Column_aliases" id="Column_aliases">Column Aliases</a></h3>
2589<p>The query language also allows column aliases to be used as <tt>ORDER BY</tt> keys.</p>
2590<div class="section">
2591<div class="section">
2592<h5><a name="Example"></a>Example</h5>
2593
2594<div>
2595<div>
2596<pre class="source">SELECT msg.authorId AS aid, COUNT(*)
2597FROM GleambookMessages msg
2598GROUP BY msg.authorId;
2599ORDER BY aid;
2600</pre></div></div>
2601
2602<p>This query returns:</p>
2603
2604<div>
2605<div>
2606<pre class="source">[ {
2607 &quot;$1&quot;: 5,
2608 &quot;aid&quot;: 1
2609}, {
2610 &quot;$1&quot;: 2,
2611 &quot;aid&quot;: 2
2612} ]
2613</pre></div></div>
2614</div></div></div></div>
2615<div class="section">
2616<h2><a name="WHERE_Clauses_and_HAVING_Clauses"></a><a name="Where_having_clauses" id="Where_having_clauses">WHERE Clauses and HAVING Clauses</a></h2>
2617<p>Both <tt>WHERE</tt> clauses and <tt>HAVING</tt> clauses are used to filter input data based on a condition expression. Only tuples for which the condition expression evaluates to <tt>TRUE</tt> are propagated. Note that if the condition expression evaluates to <tt>NULL</tt> or <tt>MISSING</tt> the input tuple will be disgarded.</p></div>
2618<div class="section">
2619<h2><a name="ORDER_BY_Clauses"></a><a name="Order_By_clauses" id="Order_By_clauses">ORDER BY Clauses</a></h2>
2620<p>The <tt>ORDER BY</tt> clause is used to globally sort data in either ascending order (i.e., <tt>ASC</tt>) or descending order (i.e., <tt>DESC</tt>). During ordering, <tt>MISSING</tt> and <tt>NULL</tt> are treated as being smaller than any other value if they are encountered in the ordering key(s). <tt>MISSING</tt> is treated as smaller than <tt>NULL</tt> if both occur in the data being sorted. The ordering of values of a given type is consistent with its type&#x2019;s &lt;= ordering; the ordering of values across types is implementation-defined but stable. The following example returns all <tt>GleambookUsers</tt> in descending order by their number of friends.</p>
2621<div class="section">
2622<div class="section">
2623<div class="section">
2624<h5><a name="Example"></a>Example</h5>
2625
2626<div>
2627<div>
2628<pre class="source"> SELECT VALUE user
2629 FROM GleambookUsers AS user
2630 ORDER BY ARRAY_COUNT(user.friendIds) DESC;
2631</pre></div></div>
2632
2633<p>This query returns:</p>
2634
2635<div>
2636<div>
2637<pre class="source"> [ {
2638 &quot;userSince&quot;: &quot;2012-08-20T10:10:00.000Z&quot;,
2639 &quot;friendIds&quot;: [
2640 2,
2641 3,
2642 6,
2643 10
2644 ],
2645 &quot;gender&quot;: &quot;F&quot;,
2646 &quot;name&quot;: &quot;MargaritaStoddard&quot;,
2647 &quot;nickname&quot;: &quot;Mags&quot;,
2648 &quot;alias&quot;: &quot;Margarita&quot;,
2649 &quot;id&quot;: 1,
2650 &quot;employment&quot;: [
2651 {
2652 &quot;organizationName&quot;: &quot;Codetechno&quot;,
2653 &quot;start-date&quot;: &quot;2006-08-06&quot;
2654 },
2655 {
2656 &quot;end-date&quot;: &quot;2010-01-26&quot;,
2657 &quot;organizationName&quot;: &quot;geomedia&quot;,
2658 &quot;start-date&quot;: &quot;2010-06-17&quot;
2659 }
2660 ]
2661 }, {
2662 &quot;userSince&quot;: &quot;2012-07-10T10:10:00.000Z&quot;,
2663 &quot;friendIds&quot;: [
2664 1,
2665 5,
2666 8,
2667 9
2668 ],
2669 &quot;name&quot;: &quot;EmoryUnk&quot;,
2670 &quot;alias&quot;: &quot;Emory&quot;,
2671 &quot;id&quot;: 3,
2672 &quot;employment&quot;: [
2673 {
2674 &quot;organizationName&quot;: &quot;geomedia&quot;,
2675 &quot;endDate&quot;: &quot;2010-01-26&quot;,
2676 &quot;startDate&quot;: &quot;2010-06-17&quot;
2677 }
2678 ]
2679 }, {
2680 &quot;userSince&quot;: &quot;2011-01-22T10:10:00.000Z&quot;,
2681 &quot;friendIds&quot;: [
2682 1,
2683 4
2684 ],
2685 &quot;name&quot;: &quot;IsbelDull&quot;,
2686 &quot;nickname&quot;: &quot;Izzy&quot;,
2687 &quot;alias&quot;: &quot;Isbel&quot;,
2688 &quot;id&quot;: 2,
2689 &quot;employment&quot;: [
2690 {
2691 &quot;organizationName&quot;: &quot;Hexviafind&quot;,
2692 &quot;startDate&quot;: &quot;2010-04-27&quot;
2693 }
2694 ]
2695 } ]
2696</pre></div></div>
2697</div></div></div></div>
2698<div class="section">
2699<h2><a name="LIMIT_Clauses"></a><a name="Limit_clauses" id="Limit_clauses">LIMIT Clauses</a></h2>
2700<p>The <tt>LIMIT</tt> clause is used to limit the result set to a specified constant size. The use of the <tt>LIMIT</tt> clause is illustrated in the next example.</p>
2701<div class="section">
2702<div class="section">
2703<div class="section">
2704<h5><a name="Example"></a>Example</h5>
2705
2706<div>
2707<div>
2708<pre class="source"> SELECT VALUE user
2709 FROM GleambookUsers AS user
2710 ORDER BY len(user.friendIds) DESC
2711 LIMIT 1;
2712</pre></div></div>
2713
2714<p>This query returns:</p>
2715
2716<div>
2717<div>
2718<pre class="source"> [ {
2719 &quot;userSince&quot;: &quot;2012-08-20T10:10:00.000Z&quot;,
2720 &quot;friendIds&quot;: [
2721 2,
2722 3,
2723 6,
2724 10
2725 ],
2726 &quot;gender&quot;: &quot;F&quot;,
2727 &quot;name&quot;: &quot;MargaritaStoddard&quot;,
2728 &quot;nickname&quot;: &quot;Mags&quot;,
2729 &quot;alias&quot;: &quot;Margarita&quot;,
2730 &quot;id&quot;: 1,
2731 &quot;employment&quot;: [
2732 {
2733 &quot;organizationName&quot;: &quot;Codetechno&quot;,
2734 &quot;start-date&quot;: &quot;2006-08-06&quot;
2735 },
2736 {
2737 &quot;end-date&quot;: &quot;2010-01-26&quot;,
2738 &quot;organizationName&quot;: &quot;geomedia&quot;,
2739 &quot;start-date&quot;: &quot;2010-06-17&quot;
2740 }
2741 ]
2742 } ]
2743</pre></div></div>
2744</div></div></div></div>
2745<div class="section">
2746<h2><a name="WITH_Clauses"></a><a name="With_clauses" id="With_clauses">WITH Clauses</a></h2>
2747<p>As in standard SQL, <tt>WITH</tt> clauses are available to improve the modularity of a query. The next query shows an example.</p>
2748<div class="section">
2749<div class="section">
2750<div class="section">
2751<h5><a name="Example"></a>Example</h5>
2752
2753<div>
2754<div>
2755<pre class="source">WITH avgFriendCount AS (
2756 SELECT VALUE AVG(ARRAY_COUNT(user.friendIds))
2757 FROM GleambookUsers AS user
2758)[0]
2759SELECT VALUE user
2760FROM GleambookUsers user
2761WHERE ARRAY_COUNT(user.friendIds) &gt; avgFriendCount;
2762</pre></div></div>
2763
2764<p>This query returns:</p>
2765
2766<div>
2767<div>
2768<pre class="source">[ {
2769 &quot;userSince&quot;: &quot;2012-08-20T10:10:00.000Z&quot;,
2770 &quot;friendIds&quot;: [
2771 2,
2772 3,
2773 6,
2774 10
2775 ],
2776 &quot;gender&quot;: &quot;F&quot;,
2777 &quot;name&quot;: &quot;MargaritaStoddard&quot;,
2778 &quot;nickname&quot;: &quot;Mags&quot;,
2779 &quot;alias&quot;: &quot;Margarita&quot;,
2780 &quot;id&quot;: 1,
2781 &quot;employment&quot;: [
2782 {
2783 &quot;organizationName&quot;: &quot;Codetechno&quot;,
2784 &quot;start-date&quot;: &quot;2006-08-06&quot;
2785 },
2786 {
2787 &quot;end-date&quot;: &quot;2010-01-26&quot;,
2788 &quot;organizationName&quot;: &quot;geomedia&quot;,
2789 &quot;start-date&quot;: &quot;2010-06-17&quot;
2790 }
2791 ]
2792}, {
2793 &quot;userSince&quot;: &quot;2012-07-10T10:10:00.000Z&quot;,
2794 &quot;friendIds&quot;: [
2795 1,
2796 5,
2797 8,
2798 9
2799 ],
2800 &quot;name&quot;: &quot;EmoryUnk&quot;,
2801 &quot;alias&quot;: &quot;Emory&quot;,
2802 &quot;id&quot;: 3,
2803 &quot;employment&quot;: [
2804 {
2805 &quot;organizationName&quot;: &quot;geomedia&quot;,
2806 &quot;endDate&quot;: &quot;2010-01-26&quot;,
2807 &quot;startDate&quot;: &quot;2010-06-17&quot;
2808 }
2809 ]
2810} ]
2811</pre></div></div>
2812
2813<p>The query is equivalent to the following, more complex, inlined form of the query:</p>
2814
2815<div>
2816<div>
2817<pre class="source">SELECT *
2818FROM GleambookUsers user
2819WHERE ARRAY_COUNT(user.friendIds) &gt;
2820 ( SELECT VALUE AVG(ARRAY_COUNT(user.friendIds))
2821 FROM GleambookUsers AS user
2822 ) [0];
2823</pre></div></div>
2824
2825<p>WITH can be particularly useful when a value needs to be used several times in a query.</p>
2826<p>Before proceeding further, notice that both the WITH query and its equivalent inlined variant include the syntax &#x201c;[0]&#x201d; &#x2013; this is due to a noteworthy difference between the query language and SQL-92. In SQL-92, whenever a scalar value is expected and it is being produced by a query expression, the SQL-92 query processor will evaluate the expression, check that there is only one row and column in the result at runtime, and then coerce the one-row/one-column tabular result into a scalar value. A JSON query language, being designed to deal with nested data and schema-less data, should not do this. Collection-valued data is perfectly legal in most contexts, and its data is schema-less, so the query processor rarely knows exactly what to expect where and such automatic conversion would often not be desirable. Thus, in the queries above, the use of &#x201c;[0]&#x201d; extracts the first (i.e., 0th) element of an array-valued query expression&#x2019;s result; this is needed above, even though the result is an array of one element, to extract the only element in the singleton array and obtain the desired scalar for the comparison.</p></div></div></div></div>
2827<div class="section">
2828<h2><a name="LET_Clauses"></a><a name="Let_clauses" id="Let_clauses">LET Clauses</a></h2>
2829<p>Similar to <tt>WITH</tt> clauses, <tt>LET</tt> clauses can be useful when a (complex) expression is used several times within a query, allowing it to be written once to make the query more concise. The next query shows an example.</p>
2830<div class="section">
2831<div class="section">
2832<div class="section">
2833<h5><a name="Example"></a>Example</h5>
2834
2835<div>
2836<div>
2837<pre class="source">SELECT u.name AS uname, messages AS messages
2838FROM GleambookUsers u
2839LET messages = (SELECT VALUE m
2840 FROM GleambookMessages m
2841 WHERE m.authorId = u.id)
2842WHERE EXISTS messages;
2843</pre></div></div>
2844
2845<p>This query lists <tt>GleambookUsers</tt> that have posted <tt>GleambookMessages</tt> and shows all authored messages for each listed user. It returns:</p>
2846
2847<div>
2848<div>
2849<pre class="source">[ {
2850 &quot;uname&quot;: &quot;MargaritaStoddard&quot;,
2851 &quot;messages&quot;: [
2852 {
2853 &quot;senderLocation&quot;: [
2854 38.97,
2855 77.49
2856 ],
2857 &quot;inResponseTo&quot;: 1,
2858 &quot;messageId&quot;: 11,
2859 &quot;authorId&quot;: 1,
2860 &quot;message&quot;: &quot; can't stand acast its plan is terrible&quot;
2861 },
2862 {
2863 &quot;senderLocation&quot;: [
2864 41.66,
2865 80.87
2866 ],
2867 &quot;inResponseTo&quot;: 4,
2868 &quot;messageId&quot;: 2,
2869 &quot;authorId&quot;: 1,
2870 &quot;message&quot;: &quot; dislike x-phone its touch-screen is horrible&quot;
2871 },
2872 {
2873 &quot;senderLocation&quot;: [
2874 37.73,
2875 97.04
2876 ],
2877 &quot;inResponseTo&quot;: 2,
2878 &quot;messageId&quot;: 4,
2879 &quot;authorId&quot;: 1,
2880 &quot;message&quot;: &quot; can't stand acast the network is horrible:(&quot;
2881 },
2882 {
2883 &quot;senderLocation&quot;: [
2884 40.33,
2885 80.87
2886 ],
2887 &quot;inResponseTo&quot;: 11,
2888 &quot;messageId&quot;: 8,
2889 &quot;authorId&quot;: 1,
2890 &quot;message&quot;: &quot; like ccast the 3G is awesome:)&quot;
2891 },
2892 {
2893 &quot;senderLocation&quot;: [
2894 42.5,
2895 70.01
2896 ],
2897 &quot;inResponseTo&quot;: 12,
2898 &quot;messageId&quot;: 10,
2899 &quot;authorId&quot;: 1,
2900 &quot;message&quot;: &quot; can't stand product-w the touch-screen is terrible&quot;
2901 }
2902 ]
2903}, {
2904 &quot;uname&quot;: &quot;IsbelDull&quot;,
2905 &quot;messages&quot;: [
2906 {
2907 &quot;senderLocation&quot;: [
2908 31.5,
2909 75.56
2910 ],
2911 &quot;inResponseTo&quot;: 1,
2912 &quot;messageId&quot;: 6,
2913 &quot;authorId&quot;: 2,
2914 &quot;message&quot;: &quot; like product-z its platform is mind-blowing&quot;
2915 },
2916 {
2917 &quot;senderLocation&quot;: [
2918 48.09,
2919 81.01
2920 ],
2921 &quot;inResponseTo&quot;: 4,
2922 &quot;messageId&quot;: 3,
2923 &quot;authorId&quot;: 2,
2924 &quot;message&quot;: &quot; like product-y the plan is amazing&quot;
2925 }
2926 ]
2927} ]
2928</pre></div></div>
2929
2930<p>This query is equivalent to the following query that does not use the <tt>LET</tt> clause:</p>
2931
2932<div>
2933<div>
2934<pre class="source">SELECT u.name AS uname, ( SELECT VALUE m
2935 FROM GleambookMessages m
2936 WHERE m.authorId = u.id
2937 ) AS messages
2938FROM GleambookUsers u
2939WHERE EXISTS ( SELECT VALUE m
2940 FROM GleambookMessages m
2941 WHERE m.authorId = u.id
2942 );
2943</pre></div></div>
2944</div></div></div></div>
2945<div class="section">
2946<h2><a name="UNION_ALL"></a><a name="Union_all" id="Union_all">UNION ALL</a></h2>
2947<p>UNION ALL can be used to combine two input arrays or multisets into one. As in SQL, there is no ordering guarantee on the contents of the output stream. However, unlike SQL, the query language does not constrain what the data looks like on the input streams; in particular, it allows heterogenity on the input and output streams. A type error will be raised if one of the inputs is not a collection. The following odd but legal query is an example:</p>
2948<div class="section">
2949<div class="section">
2950<div class="section">
2951<h5><a name="Example"></a>Example</h5>
2952
2953<div>
2954<div>
2955<pre class="source">SELECT u.name AS uname
2956FROM GleambookUsers u
2957WHERE u.id = 2
2958 UNION ALL
2959SELECT VALUE m.message
2960FROM GleambookMessages m
2961WHERE authorId=2;
2962</pre></div></div>
2963
2964<p>This query returns:</p>
2965
2966<div>
2967<div>
2968<pre class="source">[
2969 &quot; like product-z its platform is mind-blowing&quot;
2970 , {
2971 &quot;uname&quot;: &quot;IsbelDull&quot;
2972}, &quot; like product-y the plan is amazing&quot;
2973 ]
2974</pre></div></div>
2975</div></div></div></div>
2976<div class="section">
2977<h2><a name="Subqueries" id="Subqueries">Subqueries</a></h2>
2978<p>In the query language, an arbitrary subquery can appear anywhere that an expression can appear. Unlike SQL-92, as was just alluded to, the subqueries in a SELECT list or a boolean predicate need not return singleton, single-column relations. Instead, they may return arbitrary collections. For example, the following query is a variant of the prior group-by query examples; it retrieves an array of up to two &#x201c;dislike&#x201d; messages per user.</p>
2979<div class="section">
2980<div class="section">
2981<div class="section">
2982<h5><a name="Example"></a>Example</h5>
2983
2984<div>
2985<div>
2986<pre class="source">SELECT uid,
2987 (SELECT VALUE m.msg
2988 FROM msgs m
2989 WHERE m.msg.message LIKE '%dislike%'
2990 ORDER BY m.msg.messageId
2991 LIMIT 2) AS msgs
2992FROM GleambookMessages message
2993GROUP BY message.authorId AS uid GROUP AS msgs(message AS msg);
2994</pre></div></div>
2995
2996<p>For our sample data set, this query returns:</p>
2997
2998<div>
2999<div>
3000<pre class="source">[ {
3001 &quot;msgs&quot;: [
3002 {
3003 &quot;senderLocation&quot;: [
3004 41.66,
3005 80.87
3006 ],
3007 &quot;inResponseTo&quot;: 4,
3008 &quot;messageId&quot;: 2,
3009 &quot;authorId&quot;: 1,
3010 &quot;message&quot;: &quot; dislike x-phone its touch-screen is horrible&quot;
3011 }
3012 ],
3013 &quot;uid&quot;: 1
3014}, {
3015 &quot;msgs&quot;: [
3016
3017 ],
3018 &quot;uid&quot;: 2
3019} ]
3020</pre></div></div>
3021
3022<p>Note that a subquery, like a top-level <tt>SELECT</tt> statment, always returns a collection &#x2013; regardless of where within a query the subquery occurs &#x2013; and again, its result is never automatically cast into a scalar.</p></div></div></div></div>
3023<div class="section">
3024<h2><a name="Differences_from_SQL-92"></a><a name="Vs_SQL-92" id="Vs_SQL-92">Differences from SQL-92</a></h2>
3025<p>The query language offers the following additional features beyond SQL-92:</p>
3026<ul>
3027
3028<li>Fully composable and functional: A subquery can iterate over any intermediate collection and can appear anywhere in a query.</li>
3029<li>Schema-free: The query language does not assume the existence of a static schema for any data that it processes.</li>
3030<li>Correlated FROM terms: A right-side FROM term expression can refer to variables defined by FROM terms on its left.</li>
3031<li>Powerful GROUP BY: In addition to a set of aggregate functions as in standard SQL, the groups created by the <tt>GROUP BY</tt> clause are directly usable in nested queries and/or to obtain nested results.</li>
3032<li>Generalized SELECT clause: A SELECT clause can return any type of collection, while in SQL-92, a <tt>SELECT</tt> clause has to return a (homogeneous) collection of objects.</li>
3033</ul>
3034<p>The following matrix is a quick &#x201c;SQL-92 compatibility cheat sheet&#x201d; for the query language.</p>
3035<table border="0" class="table table-striped">
3036<thead>
3037
3038<tr class="a">
3039<th> Feature </th>
3040<th> The query language </th>
3041<th> SQL-92 </th>
3042<th> Why different? </th></tr>
3043</thead><tbody>
3044
3045<tr class="b">
3046<td> SELECT * </td>
3047<td> Returns nested objects </td>
3048<td> Returns flattened concatenated objects </td>
3049<td> Nested collections are 1st class citizens </td></tr>
3050<tr class="a">
3051<td> SELECT list </td>
3052<td> order not preserved </td>
3053<td> order preserved </td>
3054<td> Fields in a JSON object are not ordered </td></tr>
3055<tr class="b">
3056<td> Subquery </td>
3057<td> Returns a collection </td>
3058<td> The returned collection is cast into a scalar value if the subquery appears in a SELECT list or on one side of a comparison or as input to a function </td>
3059<td> Nested collections are 1st class citizens </td></tr>
3060<tr class="a">
3061<td> LEFT OUTER JOIN </td>
3062<td> Fills in <tt>MISSING</tt>(s) for non-matches </td>
3063<td> Fills in <tt>NULL</tt>(s) for non-matches </td>
3064<td> &#x201c;Absence&#x201d; is more appropriate than &#x201c;unknown&#x201d; here </td></tr>
3065<tr class="b">
3066<td> UNION ALL </td>
3067<td> Allows heterogeneous inputs and output </td>
3068<td> Input streams must be UNION-compatible and output field names are drawn from the first input stream </td>
3069<td> Heterogenity and nested collections are common </td></tr>
3070<tr class="a">
3071<td> IN constant_expr </td>
3072<td> The constant expression has to be an array or multiset, i.e., [..,..,&#x2026;] </td>
3073<td> The constant collection can be represented as comma-separated items in a paren pair </td>
3074<td> Nested collections are 1st class citizens </td></tr>
3075<tr class="b">
3076<td> String literal </td>
3077<td> Double quotes or single quotes </td>
3078<td> Single quotes only </td>
3079<td> Double quoted strings are pervasive </td></tr>
3080<tr class="a">
3081<td> Delimited identifiers </td>
3082<td> Backticks </td>
3083<td> Double quotes </td>
3084<td> Double quoted strings are pervasive </td></tr>
3085</tbody>
3086</table>
3087<p>The following SQL-92 features are not implemented yet. However, the query language does not conflict with these features:</p>
3088<ul>
3089
3090<li>CROSS JOIN, NATURAL JOIN, UNION JOIN</li>
3091<li>RIGHT and FULL OUTER JOIN</li>
3092<li>INTERSECT, EXCEPT, UNION with set semantics</li>
3093<li>CAST expression</li>
3094<li>COALESCE expression</li>
3095<li>ALL and SOME predicates for linking to subqueries</li>
3096<li>UNIQUE predicate (tests a collection for duplicates)</li>
3097<li>MATCH predicate (tests for referential integrity)</li>
3098<li>Row and Table constructors</li>
3099<li>Preserved order for expressions in a SELECT list</li>
3100</ul><!--
3101 ! Licensed to the Apache Software Foundation (ASF) under one
3102 ! or more contributor license agreements. See the NOTICE file
3103 ! distributed with this work for additional information
3104 ! regarding copyright ownership. The ASF licenses this file
3105 ! to you under the Apache License, Version 2.0 (the
3106 ! "License"); you may not use this file except in compliance
3107 ! with the License. You may obtain a copy of the License at
3108 !
3109 ! http://www.apache.org/licenses/LICENSE-2.0
3110 !
3111 ! Unless required by applicable law or agreed to in writing,
3112 ! software distributed under the License is distributed on an
3113 ! "AS IS" BASIS, WITHOUT WARRANTIES OR CONDITIONS OF ANY
3114 ! KIND, either express or implied. See the License for the
3115 ! specific language governing permissions and limitations
3116 ! under the License.
3117 !-->
3118
3119<h1><a name="Errors" id="Errors">4. Errors</a></h1><!--
3120 ! Licensed to the Apache Software Foundation (ASF) under one
3121 ! or more contributor license agreements. See the NOTICE file
3122 ! distributed with this work for additional information
3123 ! regarding copyright ownership. The ASF licenses this file
3124 ! to you under the Apache License, Version 2.0 (the
3125 ! "License"); you may not use this file except in compliance
3126 ! with the License. You may obtain a copy of the License at
3127 !
3128 ! http://www.apache.org/licenses/LICENSE-2.0
3129 !
3130 ! Unless required by applicable law or agreed to in writing,
3131 ! software distributed under the License is distributed on an
3132 ! "AS IS" BASIS, WITHOUT WARRANTIES OR CONDITIONS OF ANY
3133 ! KIND, either express or implied. See the License for the
3134 ! specific language governing permissions and limitations
3135 ! under the License.
3136 !-->
3137
3138<p>A query can potentially result in one of the following errors:</p>
3139<ul>
3140
3141<li>syntax error,</li>
3142<li>identifier resolution error,</li>
3143<li>type error,</li>
3144<li>resource error.</li>
3145</ul>
3146<p>If the query processor runs into any error, it will terminate the ongoing processing of the query and immediately return an error message to the client.</p></div>
3147<div class="section">
3148<h2><a name="Syntax_Errors"></a><a name="Syntax_errors" id="Syntax_errors">Syntax Errors</a></h2>
3149<p>A valid query must satisfy the grammar rules of the query language. Otherwise, a syntax error will be raised.</p>
3150<div class="section">
3151<div class="section">
3152<div class="section">
3153<h5><a name="Example"></a>Example</h5>
3154
3155<div>
3156<div>
3157<pre class="source">SELECT *
3158GleambookUsers user
3159</pre></div></div>
3160
3161<p>Since the query misses a <tt>FROM</tt> keyword before the dataset <tt>GleambookUsers</tt>, we will get a syntax error as follows:</p>
3162
3163<div>
3164<div>
3165<pre class="source">Syntax error: In line 2 &gt;&gt;GleambookUsers user;&lt;&lt; Encountered &lt;IDENTIFIER&gt; \&quot;GleambookUsers\&quot; at column 1.
3166</pre></div></div>
3167</div>
3168<div class="section">
3169<h5><a name="Example"></a>Example</h5>
3170
3171<div>
3172<div>
3173<pre class="source">SELECT *
3174FROM GleambookUsers user
3175WHERE type=&quot;advertiser&quot;;
3176</pre></div></div>
3177
3178<p>Since &#x201c;type&#x201d; is a reserved keyword in the query parser, we will get a syntax error as follows:</p>
3179
3180<div>
3181<div>
3182<pre class="source">Error: Syntax error: In line 3 &gt;&gt;WHERE type=&quot;advertiser&quot;;&lt;&lt; Encountered 'type' &quot;type&quot; at column 7.
3183==&gt; WHERE type=&quot;advertiser&quot;;
3184</pre></div></div>
3185</div></div></div></div>
3186<div class="section">
3187<h2><a name="Identifier_Resolution_Errors"></a><a name="Identifier_resolution_errors" id="Identifier_resolution_errors">Identifier Resolution Errors</a></h2>
3188<p>Referring to an undefined identifier can cause an error if the identifier cannot be successfully resolved as a valid field access.</p>
3189<div class="section">
3190<div class="section">
3191<div class="section">
3192<h5><a name="Example"></a>Example</h5>
3193
3194<div>
3195<div>
3196<pre class="source">SELECT *
3197FROM GleambookUser user;
3198</pre></div></div>
3199
3200<p>If we have a typo as above in &#x201c;GleambookUsers&#x201d; that misses the dataset name&#x2019;s ending &#x201c;s&#x201d;, we will get an identifier resolution error as follows:</p>
3201
3202<div>
3203<div>
3204<pre class="source">Error: Cannot find dataset GleambookUser in dataverse Default nor an alias with name GleambookUser!
3205</pre></div></div>
3206</div>
3207<div class="section">
3208<h5><a name="Example"></a>Example</h5>
3209
3210<div>
3211<div>
3212<pre class="source">SELECT name, message
3213FROM GleambookUsers u JOIN GleambookMessages m ON m.authorId = u.id;
3214</pre></div></div>
3215
3216<p>If the compiler cannot figure out how to resolve an unqualified field name, which will occur if there is more than one variable in scope (e.g., <tt>GleambookUsers u</tt> and <tt>GleambookMessages m</tt> as above), we will get an identifier resolution error as follows:</p>
3217
3218<div>
3219<div>
3220<pre class="source">Error: Cannot resolve ambiguous alias reference for undefined identifier name
3221</pre></div></div>
3222</div></div></div></div>
3223<div class="section">
3224<h2><a name="Type_Errors"></a><a name="Type_errors" id="Type_errors">Type Errors</a></h2>
3225<p>The query compiler does type checks based on its available type information. In addition, the query runtime also reports type errors if a data model instance it processes does not satisfy the type requirement.</p>
3226<div class="section">
3227<div class="section">
3228<div class="section">
3229<h5><a name="Example"></a>Example</h5>
3230
3231<div>
3232<div>
3233<pre class="source">abs(&quot;123&quot;);
3234</pre></div></div>
3235
3236<p>Since function <tt>abs</tt> can only process numeric input values, we will get a type error as follows:</p>
3237
3238<div>
3239<div>
3240<pre class="source">Error: Type mismatch: function abs expects its 1st input parameter to be of type tinyint, smallint, integer, bigint, float or double, but the actual input type is string
3241</pre></div></div>
3242</div></div></div></div>
3243<div class="section">
3244<h2><a name="Resource_Errors"></a><a name="Resource_errors" id="Resource_errors">Resource Errors</a></h2>
3245<p>A query can potentially exhaust system resources, such as the number of open files and disk spaces. For instance, the following two resource errors could be potentially be seen when running the system:</p>
3246
3247<div>
3248<div>
3249<pre class="source">Error: no space left on device
3250Error: too many open files
3251</pre></div></div>
3252
3253<p>The &#x201c;no space left on device&#x201d; issue usually can be fixed by cleaning up disk spaces and reserving more disk spaces for the system. The &#x201c;too many open files&#x201d; issue usually can be fixed by a system administrator, following the instructions <a class="externalLink" href="https://easyengine.io/tutorials/linux/increase-open-files-limit/">here</a>.</p><!--
3254 ! Licensed to the Apache Software Foundation (ASF) under one
3255 ! or more contributor license agreements. See the NOTICE file
3256 ! distributed with this work for additional information
3257 ! regarding copyright ownership. The ASF licenses this file
3258 ! to you under the Apache License, Version 2.0 (the
3259 ! "License"); you may not use this file except in compliance
3260 ! with the License. You may obtain a copy of the License at
3261 !
3262 ! http://www.apache.org/licenses/LICENSE-2.0
3263 !
3264 ! Unless required by applicable law or agreed to in writing,
3265 ! software distributed under the License is distributed on an
3266 ! "AS IS" BASIS, WITHOUT WARRANTIES OR CONDITIONS OF ANY
3267 ! KIND, either express or implied. See the License for the
3268 ! specific language governing permissions and limitations
3269 ! under the License.
3270 !-->
3271
3272<h1><a name="DDL_and_DML_statements" id="DDL_and_DML_statements">5. DDL and DML statements</a></h1>
3273
3274<div>
3275<div>
3276<pre class="source">Statement ::= ( ( SingleStatement )? ( &quot;;&quot; )+ )* &lt;EOF&gt;
3277SingleStatement ::= DatabaseDeclaration
3278 | FunctionDeclaration
3279 | CreateStatement
3280 | DropStatement
3281 | LoadStatement
3282 | SetStatement
3283 | InsertStatement
3284 | DeleteStatement
3285 | Query
3286</pre></div></div>
3287
3288<p>In addition to queries, an implementation of the query language needs to support statements for data definition and manipulation purposes as well as controlling the context to be used in evaluating query expressions. This section details the DDL and DML statements supported in the query language as realized today in Apache AsterixDB.</p><!--
3289 ! Licensed to the Apache Software Foundation (ASF) under one
3290 ! or more contributor license agreements. See the NOTICE file
3291 ! distributed with this work for additional information
3292 ! regarding copyright ownership. The ASF licenses this file
3293 ! to you under the Apache License, Version 2.0 (the
3294 ! "License"); you may not use this file except in compliance
3295 ! with the License. You may obtain a copy of the License at
3296 !
3297 ! http://www.apache.org/licenses/LICENSE-2.0
3298 !
3299 ! Unless required by applicable law or agreed to in writing,
3300 ! software distributed under the License is distributed on an
3301 ! "AS IS" BASIS, WITHOUT WARRANTIES OR CONDITIONS OF ANY
3302 ! KIND, either express or implied. See the License for the
3303 ! specific language governing permissions and limitations
3304 ! under the License.
3305 !-->
3306</div>
3307<div class="section">
3308<h2><a name="Lifecycle_Management_Statements"></a><a name="Lifecycle_management_statements" id="Lifecycle_management_statements">Lifecycle Management Statements</a></h2>
3309
3310<div>
3311<div>
3312<pre class="source">CreateStatement ::= &quot;CREATE&quot; ( DatabaseSpecification
3313 | TypeSpecification
3314 | DatasetSpecification
3315 | IndexSpecification
3316 | FunctionSpecification )
3317
3318QualifiedName ::= Identifier ( &quot;.&quot; Identifier )?
3319DoubleQualifiedName ::= Identifier &quot;.&quot; Identifier ( &quot;.&quot; Identifier )?
3320</pre></div></div>
3321
3322<p>The CREATE statement is used for creating dataverses as well as other persistent artifacts in a dataverse. It can be used to create new dataverses, datatypes, datasets, indexes, and user-defined query functions.</p>
3323<div class="section">
3324<h3><a name="Dataverses" id="Dataverses"> Dataverses</a></h3>
3325
3326<div>
3327<div>
3328<pre class="source">DatabaseSpecification ::= &quot;DATAVERSE&quot; Identifier IfNotExists
3329</pre></div></div>
3330
3331<p>The CREATE DATAVERSE statement is used to create new dataverses. To ease the authoring of reusable query scripts, an optional IF NOT EXISTS clause is included to allow creation to be requested either unconditionally or only if the dataverse does not already exist. If this clause is absent, an error is returned if a dataverse with the indicated name already exists.</p>
3332<p>The following example creates a new dataverse named TinySocial if one does not already exist.</p>
3333<div class="section">
3334<div class="section">
3335<h5><a name="Example"></a>Example</h5>
3336
3337<div>
3338<div>
3339<pre class="source">CREATE DATAVERSE TinySocial IF NOT EXISTS;
3340</pre></div></div>
3341</div></div></div>
3342<div class="section">
3343<h3><a name="Types" id="Types"> Types</a></h3>
3344
3345<div>
3346<div>
3347<pre class="source">TypeSpecification ::= &quot;TYPE&quot; FunctionOrTypeName IfNotExists &quot;AS&quot; ObjectTypeDef
3348FunctionOrTypeName ::= QualifiedName
3349IfNotExists ::= ( &lt;IF&gt; &lt;NOT&gt; &lt;EXISTS&gt; )?
3350TypeExpr ::= ObjectTypeDef | TypeReference | ArrayTypeDef | MultisetTypeDef
3351ObjectTypeDef ::= ( &lt;CLOSED&gt; | &lt;OPEN&gt; )? &quot;{&quot; ( ObjectField ( &quot;,&quot; ObjectField )* )? &quot;}&quot;
3352ObjectField ::= Identifier &quot;:&quot; ( TypeExpr ) ( &quot;?&quot; )?
3353NestedField ::= Identifier ( &quot;.&quot; Identifier )*
3354IndexField ::= NestedField ( &quot;:&quot; TypeReference )?
3355TypeReference ::= Identifier
3356ArrayTypeDef ::= &quot;[&quot; ( TypeExpr ) &quot;]&quot;
3357MultisetTypeDef ::= &quot;{{&quot; ( TypeExpr ) &quot;}}&quot;
3358</pre></div></div>
3359
3360<p>The CREATE TYPE statement is used to create a new named datatype. This type can then be used to create stored collections or utilized when defining one or more other datatypes. Much more information about the data model is available in the <a href="../datamodel.html">data model reference guide</a>. A new type can be a object type, a renaming of another type, an array type, or a multiset type. A object type can be defined as being either open or closed. Instances of a closed object type are not permitted to contain fields other than those specified in the create type statement. Instances of an open object type may carry additional fields, and open is the default for new types if neither option is specified.</p>
3361<p>The following example creates a new object type called GleambookUser type. Since it is defined as (defaulting to) being an open type, instances will be permitted to contain more than what is specified in the type definition. The first four fields are essentially traditional typed name/value pairs (much like SQL fields). The friendIds field is a multiset of integers. The employment field is an array of instances of another named object type, EmploymentType.</p>
3362<div class="section">
3363<div class="section">
3364<h5><a name="Example"></a>Example</h5>
3365
3366<div>
3367<div>
3368<pre class="source">CREATE TYPE GleambookUserType AS {
3369 id: int,
3370 alias: string,
3371 name: string,
3372 userSince: datetime,
3373 friendIds: {{ int }},
3374 employment: [ EmploymentType ]
3375};
3376</pre></div></div>
3377
3378<p>The next example creates a new object type, closed this time, called MyUserTupleType. Instances of this closed type will not be permitted to have extra fields, although the alias field is marked as optional and may thus be NULL or MISSING in legal instances of the type. Note that the type of the id field in the example is UUID. This field type can be used if you want to have this field be an autogenerated-PK field. (Refer to the Datasets section later for more details on such fields.)</p></div>
3379<div class="section">
3380<h5><a name="Example"></a>Example</h5>
3381
3382<div>
3383<div>
3384<pre class="source">CREATE TYPE MyUserTupleType AS CLOSED {
3385 id: uuid,
3386 alias: string?,
3387 name: string
3388};
3389</pre></div></div>
3390</div></div></div>
3391<div class="section">
3392<h3><a name="Datasets" id="Datasets"> Datasets</a></h3>
3393
3394<div>
3395<div>
3396<pre class="source">DatasetSpecification ::= ( &lt;INTERNAL&gt; )? &lt;DATASET&gt; QualifiedName &quot;(&quot; QualifiedName &quot;)&quot; IfNotExists
3397 PrimaryKey ( &lt;ON&gt; Identifier )? ( &lt;HINTS&gt; Properties )?
3398 ( &quot;USING&quot; &quot;COMPACTION&quot; &quot;POLICY&quot; CompactionPolicy ( Configuration )? )?
3399 ( &lt;WITH&gt; &lt;FILTER&gt; &lt;ON&gt; Identifier )?
3400 |
3401 &lt;EXTERNAL&gt; &lt;DATASET&gt; QualifiedName &quot;(&quot; QualifiedName &quot;)&quot; IfNotExists &lt;USING&gt; AdapterName
3402 Configuration ( &lt;HINTS&gt; Properties )?
3403 ( &lt;USING&gt; &lt;COMPACTION&gt; &lt;POLICY&gt; CompactionPolicy ( Configuration )? )?
3404AdapterName ::= Identifier
3405Configuration ::= &quot;(&quot; ( KeyValuePair ( &quot;,&quot; KeyValuePair )* )? &quot;)&quot;
3406KeyValuePair ::= &quot;(&quot; StringLiteral &quot;=&quot; StringLiteral &quot;)&quot;
3407Properties ::= ( &quot;(&quot; Property ( &quot;,&quot; Property )* &quot;)&quot; )?
3408Property ::= Identifier &quot;=&quot; ( StringLiteral | IntegerLiteral )
3409FunctionSignature ::= FunctionOrTypeName &quot;@&quot; IntegerLiteral
3410PrimaryKey ::= &lt;PRIMARY&gt; &lt;KEY&gt; NestedField ( &quot;,&quot; NestedField )* ( &lt;AUTOGENERATED&gt; )?
3411CompactionPolicy ::= Identifier
3412</pre></div></div>
3413
3414<p>The CREATE DATASET statement is used to create a new dataset. Datasets are named, multisets of object type instances; they are where data lives persistently and are the usual targets for queries. Datasets are typed, and the system ensures that their contents conform to their type definitions. An Internal dataset (the default kind) is a dataset whose content lives within and is managed by the system. It is required to have a specified unique primary key field which uniquely identifies the contained objects. (The primary key is also used in secondary indexes to identify the indexed primary data objects.)</p>
3415<p>Internal datasets contain several advanced options that can be specified when appropriate. One such option is that random primary key (UUID) values can be auto-generated by declaring the field to be UUID and putting &#x201c;AUTOGENERATED&#x201d; after the &#x201c;PRIMARY KEY&#x201d; identifier. In this case, unlike other non-optional fields, a value for the auto-generated PK field should not be provided at insertion time by the user since each object&#x2019;s primary key field value will be auto-generated by the system.</p>
3416<p>Another advanced option, when creating an Internal dataset, is to specify the merge policy to control which of the underlying LSM storage components to be merged. (The system supports Log-Structured Merge tree based physical storage for Internal datasets.) Currently the system supports four different component merging policies that can be chosen per dataset: no-merge, constant, prefix, and correlated-prefix. The no-merge policy simply never merges disk components. The constant policy merges disk components when the number of components reaches a constant number k that can be configured by the user. The prefix policy relies on both component sizes and the number of components to decide which components to merge. It works by first trying to identify the smallest ordered (oldest to newest) sequence of components such that the sequence does not contain a single component that exceeds some threshold size M and that either the sum of the component&#x2019;s sizes exceeds M or the number of components in the sequence exceeds another threshold C. If such a sequence exists, the components in the sequence are merged together to form a single component. Finally, the correlated-prefix policy is similar to the prefix policy, but it delegates the decision of merging the disk components of all the indexes in a dataset to the primary index. When the correlated-prefix policy decides that the primary index needs to be merged (using the same decision criteria as for the prefix policy), then it will issue successive merge requests on behalf of all other indexes associated with the same dataset. The system&#x2019;s default policy is the prefix policy except when there is a filter on a dataset, where the preferred policy for filters is the correlated-prefix.</p>
3417<p>Another advanced option shown in the syntax above, related to performance and mentioned above, is that a <b>filter</b> can optionally be created on a field to further optimize range queries with predicates on the filter&#x2019;s field. Filters allow some range queries to avoid searching all LSM components when the query conditions match the filter. (Refer to <a href="../filters.html">Filter-Based LSM Index Acceleration</a> for more information about filters.)</p>
3418<p>An External dataset, in contrast to an Internal dataset, has data stored outside of the system&#x2019;s control. Files living in HDFS or in the local filesystem(s) of a cluster&#x2019;s nodes are currently supported. External dataset support allows queries to treat foreign data as though it were stored in the system, making it possible to query &#x201c;legacy&#x201d; file data (for example, Hive data) without having to physically import it. When defining an External dataset, an appropriate adapter type must be selected for the desired external data. (See the <a href="../externaldata.html">Guide to External Data</a> for more information on the available adapters.)</p>
3419<p>The following example creates an Internal dataset for storing FacefookUserType objects. It specifies that their id field is their primary key.</p>
3420<div class="section">
3421<h4><a name="Example"></a>Example</h4>
3422
3423<div>
3424<div>
3425<pre class="source">CREATE INTERNAL DATASET GleambookUsers(GleambookUserType) PRIMARY KEY id;
3426</pre></div></div>
3427
3428<p>The next example creates another Internal dataset (the default kind when no dataset kind is specified) for storing MyUserTupleType objects. It specifies that the id field should be used as the primary key for the dataset. It also specifies that the id field is an auto-generated field, meaning that a randomly generated UUID value should be assigned to each incoming object by the system. (A user should therefore not attempt to provide a value for this field.) Note that the id field&#x2019;s declared type must be UUID in this case.</p></div>
3429<div class="section">
3430<h4><a name="Example"></a>Example</h4>
3431
3432<div>
3433<div>
3434<pre class="source">CREATE DATASET MyUsers(MyUserTupleType) PRIMARY KEY id AUTOGENERATED;
3435</pre></div></div>
3436
3437<p>The next example creates an External dataset for querying LineItemType objects. The choice of the <tt>hdfs</tt> adapter means that this dataset&#x2019;s data actually resides in HDFS. The example CREATE statement also provides parameters used by the hdfs adapter: the URL and path needed to locate the data in HDFS and a description of the data format.</p></div>
3438<div class="section">
3439<h4><a name="Example"></a>Example</h4>
3440
3441<div>
3442<div>
3443<pre class="source">CREATE EXTERNAL DATASET LineItem(LineItemType) USING hdfs (
3444 (&quot;hdfs&quot;=&quot;hdfs://HOST:PORT&quot;),
3445 (&quot;path&quot;=&quot;HDFS_PATH&quot;),
3446 (&quot;input-format&quot;=&quot;text-input-format&quot;),
3447 (&quot;format&quot;=&quot;delimited-text&quot;),
3448 (&quot;delimiter&quot;=&quot;|&quot;));
3449</pre></div></div>
3450</div></div>
3451<div class="section">
3452<h3><a name="Indices" id="Indices">Indices</a></h3>
3453
3454<div>
3455<div>
3456<pre class="source">IndexSpecification ::= &lt;INDEX&gt; Identifier IfNotExists &lt;ON&gt; QualifiedName
3457 &quot;(&quot; ( IndexField ) ( &quot;,&quot; IndexField )* &quot;)&quot; ( &quot;type&quot; IndexType &quot;?&quot;)?
3458 ( (&lt;NOT&gt;)? &lt;ENFORCED&gt; )?
3459IndexType ::= &lt;BTREE&gt; | &lt;RTREE&gt; | &lt;KEYWORD&gt; | &lt;NGRAM&gt; &quot;(&quot; IntegerLiteral &quot;)&quot;
3460</pre></div></div>
3461
3462<p>The CREATE INDEX statement creates a secondary index on one or more fields of a specified dataset. Supported index types include <tt>BTREE</tt> for totally ordered datatypes, <tt>RTREE</tt> for spatial data, and <tt>KEYWORD</tt> and <tt>NGRAM</tt> for textual (string) data. An index can be created on a nested field (or fields) by providing a valid path expression as an index field identifier.</p>
3463<p>An indexed field is not required to be part of the datatype associated with a dataset if the dataset&#x2019;s datatype is declared as open <b>and</b> if the field&#x2019;s type is provided along with its name and if the <tt>ENFORCED</tt> keyword is specified at the end of the index definition. <tt>ENFORCING</tt> an open field introduces a check that makes sure that the actual type of the indexed field (if the optional field exists in the object) always matches this specified (open) field type.</p>
3464<p>The following example creates a btree index called gbAuthorIdx on the authorId field of the GleambookMessages dataset. This index can be useful for accelerating exact-match queries, range search queries, and joins involving the author-id field.</p>
3465<div class="section">
3466<h4><a name="Example"></a>Example</h4>
3467
3468<div>
3469<div>
3470<pre class="source">CREATE INDEX gbAuthorIdx ON GleambookMessages(authorId) TYPE BTREE;
3471</pre></div></div>
3472
3473<p>The following example creates an open btree index called gbSendTimeIdx on the (non-predeclared) sendTime field of the GleambookMessages dataset having datetime type. This index can be useful for accelerating exact-match queries, range search queries, and joins involving the sendTime field. The index is enforced so that records that do not have the &#x201c;sendTime&#x201d; field or have a mismatched type on the field cannot be inserted into the dataset.</p></div>
3474<div class="section">
3475<h4><a name="Example"></a>Example</h4>
3476
3477<div>
3478<div>
3479<pre class="source">CREATE INDEX gbSendTimeIdx ON GleambookMessages(sendTime: datetime?) TYPE BTREE ENFORCED;
3480</pre></div></div>
3481
3482<p>The following example creates a btree index called crpUserScrNameIdx on screenName, a nested field residing within a object-valued user field in the ChirpMessages dataset. This index can be useful for accelerating exact-match queries, range search queries, and joins involving the nested screenName field. Such nested fields must be singular, i.e., one cannot index through (or on) an array-valued field.</p></div>
3483<div class="section">
3484<h4><a name="Example"></a>Example</h4>
3485
3486<div>
3487<div>
3488<pre class="source">CREATE INDEX crpUserScrNameIdx ON ChirpMessages(user.screenName) TYPE BTREE;
3489</pre></div></div>
3490
3491<p>The following example creates an rtree index called gbSenderLocIdx on the sender-location field of the GleambookMessages dataset. This index can be useful for accelerating queries that use the <a href="functions.html#spatial-intersect"><tt>spatial-intersect</tt> function</a> in a predicate involving the sender-location field.</p></div>
3492<div class="section">
3493<h4><a name="Example"></a>Example</h4>
3494
3495<div>
3496<div>
3497<pre class="source">CREATE INDEX gbSenderLocIndex ON GleambookMessages(&quot;sender-location&quot;) TYPE RTREE;
3498</pre></div></div>
3499
3500<p>The following example creates a 3-gram index called fbUserIdx on the name field of the GleambookUsers dataset. This index can be used to accelerate some similarity or substring maching queries on the name field. For details refer to the document on <a href="similarity.html#NGram_Index">similarity queries</a>.</p></div>
3501<div class="section">
3502<h4><a name="Example"></a>Example</h4>
3503
3504<div>
3505<div>
3506<pre class="source">CREATE INDEX fbUserIdx ON GleambookUsers(name) TYPE NGRAM(3);
3507</pre></div></div>
3508
3509<p>The following example creates a keyword index called fbMessageIdx on the message field of the GleambookMessages dataset. This keyword index can be used to optimize queries with token-based similarity predicates on the message field. For details refer to the document on <a href="similarity.html#Keyword_Index">similarity queries</a>.</p></div>
3510<div class="section">
3511<h4><a name="Example"></a>Example</h4>
3512
3513<div>
3514<div>
3515<pre class="source">CREATE INDEX fbMessageIdx ON GleambookMessages(message) TYPE KEYWORD;
3516</pre></div></div>
3517<!--
3518 ! Licensed to the Apache Software Foundation (ASF) under one
3519 ! or more contributor license agreements. See the NOTICE file
3520 ! distributed with this work for additional information
3521 ! regarding copyright ownership. The ASF licenses this file
3522 ! to you under the Apache License, Version 2.0 (the
3523 ! "License"); you may not use this file except in compliance
3524 ! with the License. You may obtain a copy of the License at
3525 !
3526 ! http://www.apache.org/licenses/LICENSE-2.0
3527 !
3528 ! Unless required by applicable law or agreed to in writing,
3529 ! software distributed under the License is distributed on an
3530 ! "AS IS" BASIS, WITHOUT WARRANTIES OR CONDITIONS OF ANY
3531 ! KIND, either express or implied. See the License for the
3532 ! specific language governing permissions and limitations
3533 ! under the License.
3534 !-->
3535
3536<p>The following example creates an open btree index called gbReadTimeIdx on the (non-predeclared) readTime field of the GleambookMessages dataset having datetime type. This index can be useful for accelerating exact-match queries, range search queries, and joins involving the <tt>readTime</tt> field. The index is not enforced so that records that do not have the <tt>readTime</tt> field or have a mismatched type on the field can still be inserted into the dataset.</p></div>
3537<div class="section">
3538<h4><a name="Example"></a>Example</h4>
3539
3540<div>
3541<div>
3542<pre class="source">CREATE INDEX gbReadTimeIdx ON GleambookMessages(readTime: datetime?);
3543</pre></div></div>
3544<!--
3545 ! Licensed to the Apache Software Foundation (ASF) under one
3546 ! or more contributor license agreements. See the NOTICE file
3547 ! distributed with this work for additional information
3548 ! regarding copyright ownership. The ASF licenses this file
3549 ! to you under the Apache License, Version 2.0 (the
3550 ! "License"); you may not use this file except in compliance
3551 ! with the License. You may obtain a copy of the License at
3552 !
3553 ! http://www.apache.org/licenses/LICENSE-2.0
3554 !
3555 ! Unless required by applicable law or agreed to in writing,
3556 ! software distributed under the License is distributed on an
3557 ! "AS IS" BASIS, WITHOUT WARRANTIES OR CONDITIONS OF ANY
3558 ! KIND, either express or implied. See the License for the
3559 ! specific language governing permissions and limitations
3560 ! under the License.
3561 !-->
3562</div></div>
3563<div class="section">
3564<h3><a name="Functions" id="Functions"> Functions</a></h3>
3565<p>The create function statement creates a <b>named</b> function that can then be used and reused in queries. The body of a function can be any query expression involving the function&#x2019;s parameters.</p>
3566
3567<div>
3568<div>
3569<pre class="source">FunctionSpecification ::= &quot;FUNCTION&quot; FunctionOrTypeName IfNotExists ParameterList &quot;{&quot; Expression &quot;}&quot;
3570</pre></div></div>
3571
3572<p>The following is an example of a CREATE FUNCTION statement which is similar to our earlier DECLARE FUNCTION example. It differs from that example in that it results in a function that is persistently registered by name in the specified dataverse (the current dataverse being used, if not otherwise specified).</p>
3573<div class="section">
3574<div class="section">
3575<h5><a name="Example"></a>Example</h5>
3576
3577<div>
3578<div>
3579<pre class="source">CREATE FUNCTION friendInfo(userId) {
3580 (SELECT u.id, u.name, len(u.friendIds) AS friendCount
3581 FROM GleambookUsers u
3582 WHERE u.id = userId)[0]
3583 };
3584</pre></div></div>
3585</div></div></div>
3586<div class="section">
3587<h3><a name="Removal" id="Removal"> Removal</a></h3>
3588
3589<div>
3590<div>
3591<pre class="source">DropStatement ::= &quot;DROP&quot; ( &quot;DATAVERSE&quot; Identifier IfExists
3592 | &quot;TYPE&quot; FunctionOrTypeName IfExists
3593 | &quot;DATASET&quot; QualifiedName IfExists
3594 | &quot;INDEX&quot; DoubleQualifiedName IfExists
3595 | &quot;FUNCTION&quot; FunctionSignature IfExists )
3596IfExists ::= ( &quot;IF&quot; &quot;EXISTS&quot; )?
3597</pre></div></div>
3598
3599<p>The DROP statement is the inverse of the CREATE statement. It can be used to drop dataverses, datatypes, datasets, indexes, and functions.</p>
3600<p>The following examples illustrate some uses of the DROP statement.</p>
3601<div class="section">
3602<div class="section">
3603<h5><a name="Example"></a>Example</h5>
3604
3605<div>
3606<div>
3607<pre class="source">DROP DATASET GleambookUsers IF EXISTS;
3608
3609DROP INDEX GleambookMessages.gbSenderLocIndex;
3610
3611DROP TYPE TinySocial2.GleambookUserType;
3612
3613DROP FUNCTION friendInfo@1;
3614
3615DROP DATAVERSE TinySocial;
3616</pre></div></div>
3617
3618<p>When an artifact is dropped, it will be droppped from the current dataverse if none is specified (see the DROP DATASET example above) or from the specified dataverse (see the DROP TYPE example above) if one is specified by fully qualifying the artifact name in the DROP statement. When specifying an index to drop, the index name must be qualified by the dataset that it indexes. When specifying a function to drop, since the query language allows functions to be overloaded by their number of arguments, the identifying name of the function to be dropped must explicitly include that information. (<tt>friendInfo@1</tt> above denotes the 1-argument function named friendInfo in the current dataverse.)</p></div></div></div>
3619<div class="section">
3620<h3><a name="Load_Statement"></a><a name="Load_statement" id="Load_statement">Load Statement</a></h3>
3621
3622<div>
3623<div>
3624<pre class="source">LoadStatement ::= &lt;LOAD&gt; &lt;DATASET&gt; QualifiedName &lt;USING&gt; AdapterName Configuration ( &lt;PRE-SORTED&gt; )?
3625</pre></div></div>
3626
3627<p>The LOAD statement is used to initially populate a dataset via bulk loading of data from an external file. An appropriate adapter must be selected to handle the nature of the desired external data. The LOAD statement accepts the same adapters and the same parameters as discussed earlier for External datasets. (See the <a href="externaldata.html">guide to external data</a> for more information on the available adapters.) If a dataset has an auto-generated primary key field, the file to be imported should not include that field in it.</p>
3628<p>The following example shows how to bulk load the GleambookUsers dataset from an external file containing data that has been prepared in ADM (Asterix Data Model) format.</p>
3629<div class="section">
3630<div class="section">
3631<h5><a name="Example"></a>Example</h5>
3632
3633<div>
3634<div>
3635<pre class="source"> LOAD DATASET GleambookUsers USING localfs
3636 ((&quot;path&quot;=&quot;127.0.0.1:///Users/bignosqlfan/tinysocialnew/gbu.adm&quot;),(&quot;format&quot;=&quot;adm&quot;));
3637</pre></div></div>
3638<!--
3639 ! Licensed to the Apache Software Foundation (ASF) under one
3640 ! or more contributor license agreements. See the NOTICE file
3641 ! distributed with this work for additional information
3642 ! regarding copyright ownership. The ASF licenses this file
3643 ! to you under the Apache License, Version 2.0 (the
3644 ! "License"); you may not use this file except in compliance
3645 ! with the License. You may obtain a copy of the License at
3646 !
3647 ! http://www.apache.org/licenses/LICENSE-2.0
3648 !
3649 ! Unless required by applicable law or agreed to in writing,
3650 ! software distributed under the License is distributed on an
3651 ! "AS IS" BASIS, WITHOUT WARRANTIES OR CONDITIONS OF ANY
3652 ! KIND, either express or implied. See the License for the
3653 ! specific language governing permissions and limitations
3654 ! under the License.
3655 !-->
3656</div></div></div></div>
3657<div class="section">
3658<h2><a name="Modification_statements" id="Modification_statements">Modification statements</a></h2>
3659<div class="section">
3660<h3><a name="INSERTs"></a><a name="Inserts" id="Inserts">INSERTs</a></h3>
3661
3662<div>
3663<div>
3664<pre class="source">InsertStatement ::= &lt;INSERT&gt; &lt;INTO&gt; QualifiedName Query
3665</pre></div></div>
3666
3667<p>The INSERT statement is used to insert new data into a dataset. The data to be inserted comes from a query expression. This expression can be as simple as a constant expression, or in general it can be any legal query. If the target dataset has an auto-generated primary key field, the insert statement should not include a value for that field in it. (The system will automatically extend the provided object with this additional field and a corresponding value.) Insertion will fail if the dataset already has data with the primary key value(s) being inserted.</p>
3668<p>Inserts are processed transactionally by the system. The transactional scope of each insert transaction is the insertion of a single object plus its affiliated secondary index entries (if any). If the query part of an insert returns a single object, then the INSERT statement will be a single, atomic transaction. If the query part returns multiple objects, each object being inserted will be treated as a separate tranaction. The following example illustrates a query-based insertion.</p>
3669<div class="section">
3670<div class="section">
3671<h5><a name="Example"></a>Example</h5>
3672
3673<div>
3674<div>
3675<pre class="source">INSERT INTO UsersCopy (SELECT VALUE user FROM GleambookUsers user)
3676</pre></div></div>
3677</div></div></div>
3678<div class="section">
3679<h3><a name="UPSERTs"></a><a name="Upserts" id="Upserts">UPSERTs</a></h3>
3680
3681<div>
3682<div>
3683<pre class="source">UpsertStatement ::= &lt;UPSERT&gt; &lt;INTO&gt; QualifiedName Query
3684</pre></div></div>
3685
3686<p>The UPSERT statement syntactically mirrors the INSERT statement discussed above. The difference lies in its semantics, which for UPSERT are &#x201c;add or replace&#x201d; instead of the INSERT &#x201c;add if not present, else error&#x201d; semantics. Whereas an INSERT can fail if another object already exists with the specified key, the analogous UPSERT will replace the previous object&#x2019;s value with that of the new object in such cases.</p>
3687<p>The following example illustrates a query-based upsert operation.</p>
3688<div class="section">
3689<div class="section">
3690<h5><a name="Example"></a>Example</h5>
3691
3692<div>
3693<div>
3694<pre class="source">UPSERT INTO UsersCopy (SELECT VALUE user FROM GleambookUsers user)
3695</pre></div></div>
3696
3697<p>*Editor&#x2019;s note: Upserts currently work in AQL but are not yet enabled (at the moment) in the current query language.</p></div></div></div>
3698<div class="section">
3699<h3><a name="DELETEs"></a><a name="Deletes" id="Deletes">DELETEs</a></h3>
3700
3701<div>
3702<div>
3703<pre class="source">DeleteStatement ::= &lt;DELETE&gt; &lt;FROM&gt; QualifiedName ( ( &lt;AS&gt; )? Variable )? ( &lt;WHERE&gt; Expression )?
3704</pre></div></div>
3705
3706<p>The DELETE statement is used to delete data from a target dataset. The data to be deleted is identified by a boolean expression involving the variable bound to the target dataset in the DELETE statement.</p>
3707<p>Deletes are processed transactionally by the system. The transactional scope of each delete transaction is the deletion of a single object plus its affiliated secondary index entries (if any). If the boolean expression for a delete identifies a single object, then the DELETE statement itself will be a single, atomic transaction. If the expression identifies multiple objects, then each object deleted will be handled as a separate transaction.</p>
3708<p>The following examples illustrate single-object deletions.</p>
3709<div class="section">
3710<div class="section">
3711<h5><a name="Example"></a>Example</h5>
3712
3713<div>
3714<div>
3715<pre class="source">DELETE FROM GleambookUsers user WHERE user.id = 8;
3716</pre></div></div>
3717</div>
3718<div class="section">
3719<h5><a name="Example"></a>Example</h5>
3720
3721<div>
3722<div>
3723<pre class="source">DELETE FROM GleambookUsers WHERE id = 5;
3724</pre></div></div>
3725<!--
3726 ! Licensed to the Apache Software Foundation (ASF) under one
3727 ! or more contributor license agreements. See the NOTICE file
3728 ! distributed with this work for additional information
3729 ! regarding copyright ownership. The ASF licenses this file
3730 ! to you under the Apache License, Version 2.0 (the
3731 ! "License"); you may not use this file except in compliance
3732 ! with the License. You may obtain a copy of the License at
3733 !
3734 ! http://www.apache.org/licenses/LICENSE-2.0
3735 !
3736 ! Unless required by applicable law or agreed to in writing,
3737 ! software distributed under the License is distributed on an
3738 ! "AS IS" BASIS, WITHOUT WARRANTIES OR CONDITIONS OF ANY
3739 ! KIND, either express or implied. See the License for the
3740 ! specific language governing permissions and limitations
3741 ! under the License.
3742 !-->
3743
3744<h1><a name="Reserved_keywords" id="Reserved_keywords">Appendix 1. Reserved keywords</a></h1><!--
3745 ! Licensed to the Apache Software Foundation (ASF) under one
3746 ! or more contributor license agreements. See the NOTICE file
3747 ! distributed with this work for additional information
3748 ! regarding copyright ownership. The ASF licenses this file
3749 ! to you under the Apache License, Version 2.0 (the
3750 ! "License"); you may not use this file except in compliance
3751 ! with the License. You may obtain a copy of the License at
3752 !
3753 ! http://www.apache.org/licenses/LICENSE-2.0
3754 !
3755 ! Unless required by applicable law or agreed to in writing,
3756 ! software distributed under the License is distributed on an
3757 ! "AS IS" BASIS, WITHOUT WARRANTIES OR CONDITIONS OF ANY
3758 ! KIND, either express or implied. See the License for the
3759 ! specific language governing permissions and limitations
3760 ! under the License.
3761 !-->
3762
3763<p>All reserved keywords are listed in the following table:</p>
3764<table border="0" class="table table-striped">
3765<thead>
3766
3767<tr class="a">
3768<th> </th>
3769<th> </th>
3770<th> </th>
3771<th> </th>
3772<th> </th>
3773<th> </th></tr>
3774</thead><tbody>
3775
3776<tr class="b">
3777<td> AND </td>
3778<td> ANY </td>
3779<td> APPLY </td>
3780<td> AS </td>
3781<td> ASC </td>
3782<td> AT </td></tr>
3783<tr class="a">
3784<td> AUTOGENERATED </td>
3785<td> BETWEEN </td>
3786<td> BTREE </td>
3787<td> BY </td>
3788<td> CASE </td>
3789<td> CLOSED </td></tr>
3790<tr class="b">
3791<td> CREATE </td>
3792<td> COMPACTION </td>
3793<td> COMPACT </td>
3794<td> CONNECT </td>
3795<td> CORRELATE </td>
3796<td> DATASET </td></tr>
3797<tr class="a">
3798<td> COLLECTION </td>
3799<td> DATAVERSE </td>
3800<td> DECLARE </td>
3801<td> DEFINITION </td>
3802<td> DECLARE </td>
3803<td> DEFINITION </td></tr>
3804<tr class="b">
3805<td> DELETE </td>
3806<td> DESC </td>
3807<td> DISCONNECT </td>
3808<td> DISTINCT </td>
3809<td> DROP </td>
3810<td> ELEMENT </td></tr>
3811<tr class="a">
3812<td> ELEMENT </td>
3813<td> EXPLAIN </td>
3814<td> ELSE </td>
3815<td> ENFORCED </td>
3816<td> END </td>
3817<td> EVERY </td></tr>
3818<tr class="b">
3819<td> EXCEPT </td>
3820<td> EXIST </td>
3821<td> EXTERNAL </td>
3822<td> FEED </td>
3823<td> FILTER </td>
3824<td> FLATTEN </td></tr>
3825<tr class="a">
3826<td> FOR </td>
3827<td> FROM </td>
3828<td> FULL </td>
3829<td> FUNCTION </td>
3830<td> GROUP </td>
3831<td> HAVING </td></tr>
3832<tr class="b">
3833<td> HINTS </td>
3834<td> IF </td>
3835<td> INTO </td>
3836<td> IN </td>
3837<td> INDEX </td>
3838<td> INGESTION </td></tr>
3839<tr class="a">
3840<td> INNER </td>
3841<td> INSERT </td>
3842<td> INTERNAL </td>
3843<td> INTERSECT </td>
3844<td> IS </td>
3845<td> JOIN </td></tr>
3846<tr class="b">
3847<td> KEYWORD </td>
3848<td> LEFT </td>
3849<td> LETTING </td>
3850<td> LET </td>
3851<td> LIKE </td>
3852<td> LIMIT </td></tr>
3853<tr class="a">
3854<td> LOAD </td>
3855<td> NODEGROUP </td>
3856<td> NGRAM </td>
3857<td> NOT </td>
3858<td> OFFSET </td>
3859<td> ON </td></tr>
3860<tr class="b">
3861<td> OPEN </td>
3862<td> OR </td>
3863<td> ORDER </td>
3864<td> OUTER </td>
3865<td> OUTPUT </td>
3866<td> PATH </td></tr>
3867<tr class="a">
3868<td> POLICY </td>
3869<td> PRE-SORTED </td>
3870<td> PRIMARY </td>
3871<td> RAW </td>
3872<td> REFRESH </td>
3873<td> RETURN </td></tr>
3874<tr class="b">
3875<td> RTREE </td>
3876<td> RUN </td>
3877<td> SATISFIES </td>
3878<td> SECONDARY </td>
3879<td> SELECT </td>
3880<td> SET </td></tr>
3881<tr class="a">
3882<td> SOME </td>
3883<td> TEMPORARY </td>
3884<td> THEN </td>
3885<td> TYPE </td>
3886<td> UNKNOWN </td>
3887<td> UNNEST </td></tr>
3888<tr class="b">
3889<td> UPDATE </td>
3890<td> USE </td>
3891<td> USING </td>
3892<td> VALUE </td>
3893<td> WHEN </td>
3894<td> WHERE </td></tr>
3895<tr class="a">
3896<td> WITH </td>
3897<td> WRITE </td>
3898<td> </td>
3899<td> </td>
3900<td> </td>
3901<td> </td></tr>
3902</tbody>
3903</table><!--
3904 ! Licensed to the Apache Software Foundation (ASF) under one
3905 ! or more contributor license agreements. See the NOTICE file
3906 ! distributed with this work for additional information
3907 ! regarding copyright ownership. The ASF licenses this file
3908 ! to you under the Apache License, Version 2.0 (the
3909 ! "License"); you may not use this file except in compliance
3910 ! with the License. You may obtain a copy of the License at
3911 !
3912 ! http://www.apache.org/licenses/LICENSE-2.0
3913 !
3914 ! Unless required by applicable law or agreed to in writing,
3915 ! software distributed under the License is distributed on an
3916 ! "AS IS" BASIS, WITHOUT WARRANTIES OR CONDITIONS OF ANY
3917 ! KIND, either express or implied. See the License for the
3918 ! specific language governing permissions and limitations
3919 ! under the License.
3920 !-->
3921</div></div></div></div>
3922<div class="section">
3923<h2><a name="Appendix_2._Performance_Tuning"></a><a name="Performance_tuning" id="Performance_tuning">Appendix 2. Performance Tuning</a></h2><!--
3924 ! Licensed to the Apache Software Foundation (ASF) under one
3925 ! or more contributor license agreements. See the NOTICE file
3926 ! distributed with this work for additional information
3927 ! regarding copyright ownership. The ASF licenses this file
3928 ! to you under the Apache License, Version 2.0 (the
3929 ! "License"); you may not use this file except in compliance
3930 ! with the License. You may obtain a copy of the License at
3931 !
3932 ! http://www.apache.org/licenses/LICENSE-2.0
3933 !
3934 ! Unless required by applicable law or agreed to in writing,
3935 ! software distributed under the License is distributed on an
3936 ! "AS IS" BASIS, WITHOUT WARRANTIES OR CONDITIONS OF ANY
3937 ! KIND, either express or implied. See the License for the
3938 ! specific language governing permissions and limitations
3939 ! under the License.
3940 !-->
3941
3942<p>The SET statement can be used to override some cluster-wide configuration parameters for a specific request:</p>
3943
3944<div>
3945<div>
3946<pre class="source">SET &lt;IDENTIFIER&gt; &lt;STRING_LITERAL&gt;
3947</pre></div></div>
3948
3949<p>As parameter identifiers are qualified names (containing a &#x2018;.&#x2019;) they have to be escaped using backticks (``). Note that changing query parameters will not affect query correctness but only impact performance characteristics, such as response time and throughput.</p></div>
3950<div class="section">
3951<h2><a name="Parallelism_Parameter"></a><a name="Parallelism_parameter" id="Parallelism_parameter">Parallelism Parameter</a></h2>
3952<p>The system can execute each request using multiple cores on multiple machines (a.k.a., partitioned parallelism) in a cluster. A user can manually specify the maximum execution parallelism for a request to scale it up and down using the following parameter:</p>
3953<ul>
3954
3955<li><b>compiler.parallelism</b>: the maximum number of CPU cores can be used to process a query. There are three cases of the value <i>p</i> for compiler.parallelism:
3956<ul>
3957
3958<li>
3959
3960<p><i>p</i> &lt; 0 or <i>p</i> &gt; the total number of cores in a cluster: the system will use all available cores in the cluster;</p>
3961</li>
3962<li>
3963
3964<p><i>p</i> = 0 (the default): the system will use the storage parallelism (the number of partitions of stored datasets) as the maximum parallelism for query processing;</p>
3965</li>
3966<li>
3967
3968<p>all other cases: the system will use the user-specified number as the maximum number of CPU cores to use for executing the query.</p>
3969</li>
3970</ul>
3971</li>
3972</ul>
3973<div class="section">
3974<div class="section">
3975<div class="section">
3976<h5><a name="Example"></a>Example</h5>
3977
3978<div>
3979<div>
3980<pre class="source">SET `compiler.parallelism` &quot;16&quot;;
3981
3982SELECT u.name AS uname, m.message AS message
3983FROM GleambookUsers u JOIN GleambookMessages m ON m.authorId = u.id;
3984</pre></div></div>
3985</div></div></div></div>
3986<div class="section">
3987<h2><a name="Memory_Parameters"></a><a name="Memory_parameters" id="Memory_parameters">Memory Parameters</a></h2>
3988<p>In the system, each blocking runtime operator such as join, group-by and order-by works within a fixed memory budget, and can gracefully spill to disks if the memory budget is smaller than the amount of data they have to hold. A user can manually configure the memory budget of those operators within a query. The supported configurable memory parameters are:</p>
3989<ul>
3990
3991<li>
3992
3993<p><b>compiler.groupmemory</b>: the memory budget that each parallel group-by operator instance can use; 32MB is the default budget.</p>
3994</li>
3995<li>
3996
3997<p><b>compiler.sortmemory</b>: the memory budget that each parallel sort operator instance can use; 32MB is the default budget.</p>
3998</li>
3999<li>
4000
4001<p><b>compiler.joinmemory</b>: the memory budget that each parallel hash join operator instance can use; 32MB is the default budget.</p>
4002</li>
4003</ul>
4004<p>For each memory budget value, you can use a 64-bit integer value with a 1024-based binary unit suffix (for example, B, KB, MB, GB). If there is no user-provided suffix, &#x201c;B&#x201d; is the default suffix. See the following examples.</p>
4005<div class="section">
4006<div class="section">
4007<div class="section">
4008<h5><a name="Example"></a>Example</h5>
4009
4010<div>
4011<div>
4012<pre class="source">SET `compiler.groupmemory` &quot;64MB&quot;;
4013
4014SELECT msg.authorId, COUNT(*)
4015FROM GleambookMessages msg
4016GROUP BY msg.authorId;
4017</pre></div></div>
4018</div>
4019<div class="section">
4020<h5><a name="Example"></a>Example</h5>
4021
4022<div>
4023<div>
4024<pre class="source">SET `compiler.sortmemory` &quot;67108864&quot;;
4025
4026SELECT VALUE user
4027FROM GleambookUsers AS user
4028ORDER BY ARRAY_LENGTH(user.friendIds) DESC;
4029</pre></div></div>
4030</div>
4031<div class="section">
4032<h5><a name="Example"></a>Example</h5>
4033
4034<div>
4035<div>
4036<pre class="source">SET `compiler.joinmemory` &quot;132000KB&quot;;
4037
4038SELECT u.name AS uname, m.message AS message
4039FROM GleambookUsers u JOIN GleambookMessages m ON m.authorId = u.id;
4040</pre></div></div>
4041<!--
4042 ! Licensed to the Apache Software Foundation (ASF) under one
4043 ! or more contributor license agreements. See the NOTICE file
4044 ! distributed with this work for additional information
4045 ! regarding copyright ownership. The ASF licenses this file
4046 ! to you under the Apache License, Version 2.0 (the
4047 ! "License"); you may not use this file except in compliance
4048 ! with the License. You may obtain a copy of the License at
4049 !
4050 ! http://www.apache.org/licenses/LICENSE-2.0
4051 !
4052 ! Unless required by applicable law or agreed to in writing,
4053 ! software distributed under the License is distributed on an
4054 ! "AS IS" BASIS, WITHOUT WARRANTIES OR CONDITIONS OF ANY
4055 ! KIND, either express or implied. See the License for the
4056 ! specific language governing permissions and limitations
4057 ! under the License.
4058 !-->
4059</div></div></div></div>
4060<div class="section">
4061<h2><a name="Controlling_Index-Only-Plan_Parameter"></a><a name="Index_Only" id="Index_Only">Controlling Index-Only-Plan Parameter</a></h2>
4062<p>By default, the system tries to build an index-only plan whenever utilizing a secondary index is possible. For example, if a SELECT or JOIN query can utilize an enforced B+Tree or R-Tree index on a field, the optimizer checks whether a secondary-index search alone can generate the result that the query asks for. It mainly checks two conditions: (1) predicates used in WHERE only uses the primary key field and/or secondary key field and (2) the result does not return any other fields. If these two conditions hold, it builds an index-only plan. Since an index-only plan only searches a secondary-index to answer a query, it is faster than a non-index-only plan that needs to search the primary index. However, this index-only plan can be turned off per query by setting the following parameter.</p>
4063<ul>
4064
4065<li><b>noindexonly</b>: if this is set to true, the index-only-plan will not be applied; the default value is false.</li>
4066</ul>
4067<div class="section">
4068<div class="section">
4069<div class="section">
4070<h5><a name="Example"></a>Example</h5>
4071
4072<div>
4073<div>
4074<pre class="source">SET noindexonly 'true';
4075
4076SELECT m.message AS message
4077FROM GleambookMessages m where m.message = &quot; love product-b its shortcut-menu is awesome:)&quot;;
4078</pre></div></div>
4079<!--
4080 ! Licensed to the Apache Software Foundation (ASF) under one
4081 ! or more contributor license agreements. See the NOTICE file
4082 ! distributed with this work for additional information
4083 ! regarding copyright ownership. The ASF licenses this file
4084 ! to you under the Apache License, Version 2.0 (the
4085 ! "License"); you may not use this file except in compliance
4086 ! with the License. You may obtain a copy of the License at
4087 !
4088 ! http://www.apache.org/licenses/LICENSE-2.0
4089 !
4090 ! Unless required by applicable law or agreed to in writing,
4091 ! software distributed under the License is distributed on an
4092 ! "AS IS" BASIS, WITHOUT WARRANTIES OR CONDITIONS OF ANY
4093 ! KIND, either express or implied. See the License for the
4094 ! specific language governing permissions and limitations
4095 ! under the License.
4096 !-->
4097</div></div></div></div>
4098<div class="section">
4099<h2><a name="Appendix_3._Variable_Bindings_and_Name_Resolution"></a><a name="Variable_bindings_and_name_resolution" id="Variable_bindings_and_name_resolution">Appendix 3. Variable Bindings and Name Resolution</a></h2><!--
4100 ! Licensed to the Apache Software Foundation (ASF) under one
4101 ! or more contributor license agreements. See the NOTICE file
4102 ! distributed with this work for additional information
4103 ! regarding copyright ownership. The ASF licenses this file
4104 ! to you under the Apache License, Version 2.0 (the
4105 ! "License"); you may not use this file except in compliance
4106 ! with the License. You may obtain a copy of the License at
4107 !
4108 ! http://www.apache.org/licenses/LICENSE-2.0
4109 !
4110 ! Unless required by applicable law or agreed to in writing,
4111 ! software distributed under the License is distributed on an
4112 ! "AS IS" BASIS, WITHOUT WARRANTIES OR CONDITIONS OF ANY
4113 ! KIND, either express or implied. See the License for the
4114 ! specific language governing permissions and limitations
4115 ! under the License.
4116 !-->
4117
4118<p>In this Appendix, we&#x2019;ll look at how variables are bound and how names are resolved. Names can appear in every clause of a query. Sometimes a name consists of just a single identifier, e.g., <tt>region</tt> or <tt>revenue</tt>. More often a name will consist of two identifiers separated by a dot, e.g., <tt>customer.address</tt>. Occasionally a name may have more than two identifiers, e.g., <tt>policy.owner.address.zipcode</tt>. <i>Resolving</i> a name means determining exactly what the (possibly multi-part) name refers to. It is necessary to have well-defined rules for how to resolve a name in cases of ambiguity. (In the absence of schemas, such cases arise more commonly, and also differently, than they do in SQL.)</p>
4119<p>The basic job of each clause in a query block is to bind variables. Each clause sees the variables bound by previous clauses and may bind additional variables. Names are always resolved with respect to the variables that are bound (&#x201c;in scope&#x201d;) at the place where the name use in question occurs. It is possible that the name resolution process will fail, which may lead to an empty result or an error message.</p>
4120<p>One important bit of background: When the system is reading a query and resolving its names, it has a list of all the available dataverses and datasets. As a result, it knows whether <tt>a.b</tt> is a valid name for dataset <tt>b</tt> in dataverse <tt>a</tt>. However, the system does not in general have knowledge of the schemas of the data inside the datasets; remember that this is a much more open world. As a result, in general the system cannot know whether any object in a particular dataset will have a field named <tt>c</tt>. These assumptions affect how errors are handled. If you try to access dataset <tt>a.b</tt> and no dataset by that name exists, you will get an error and your query will not run. However, if you try to access a field <tt>c</tt> in a collection of objects, your query will run and return <tt>missing</tt> for each object that doesn&#x2019;t have a field named <tt>c</tt> &#x2013; this is because it&#x2019;s possible that some object (someday) could have such a field.</p></div>
4121<div class="section">
4122<h2><a name="Binding_Variables"></a><a name="Binding_variables" id="Binding_variables">Binding Variables</a></h2>
4123<p>Variables can be bound in the following ways:</p>
4124<ol style="list-style-type: decimal">
4125
4126<li>
4127
4128<p>WITH and LET clauses bind a variable to the result of an expression in a straightforward way</p>
4129<p>Examples:</p>
4130<p><tt>WITH cheap_parts AS (SELECT partno FROM parts WHERE price &lt; 100)</tt> binds the variable <tt>cheap_parts</tt> to the result of the subquery.</p>
4131<p><tt>LET pay = salary + bonus</tt> binds the variable <tt>pay</tt> to the result of evaluating the expression <tt>salary + bonus</tt>.</p>
4132</li>
4133<li>
4134
4135<p>FROM, GROUP BY, and SELECT clauses have optional AS subclauses that contain an expression and a name (called an <i>iteration variable</i> in a FROM clause, or an alias in GROUP BY or SELECT.)</p>
4136<p>Examples:</p>
4137<p><tt>FROM customer AS c, order AS o</tt></p>
4138<p><tt>GROUP BY salary + bonus AS total_pay</tt></p>
4139<p><tt>SELECT MAX(price) AS highest_price</tt></p>
4140<p>An AS subclause always binds the name (as a variable) to the result of the expression (or, in the case of a FROM clause, to the <i>individual members</i> of the collection identified by the expression.)</p>
4141<p>It&#x2019;s always a good practice to use the keyword AS when defining an alias or iteration variable. However, as in SQL, the syntax allows the keyword AS to be omitted. For example, the FROM clause above could have been written like this:</p>
4142<p><tt>FROM customer c, order o</tt></p>
4143<p>Omitting the keyword AS does not affect the binding of variables. The FROM clause in this example binds variables c and o whether the keyword AS is used or not.</p>
4144<p>In certain cases, a variable is automatically bound even if no alias or variable-name is specified. Whenever an expression could have been followed by an AS subclause, if the expression consists of a simple name or a path expression, that expression binds a variable whose name is the same as the simple name or the last step in the path expression. Here are some examples:</p>
4145<p><tt>FROM customer, order</tt> binds iteration variables named <tt>customer</tt> and <tt>order</tt></p>
4146<p><tt>GROUP BY address.zipcode</tt> binds a variable named <tt>zipcode</tt></p>
4147<p><tt>SELECT item[0].price</tt> binds a variable named <tt>price</tt></p>
4148<p>Note that a FROM clause iterates over a collection (usually a dataset), binding a variable to each member of the collection in turn. The name of the collection remains in scope, but it is not a variable. For example, consider this FROM clause used in a self-join:</p>
4149<p><tt>FROM customer AS c1, customer AS c2</tt></p>
4150<p>This FROM clause joins the customer dataset to itself, binding the iteration variables c1 and c2 to objects in the left-hand-side and right-hand-side of the join, respectively. After the FROM clause, c1 and c2 are in scope as variables, and customer remains accessible as a dataset name but not as a variable.</p>
4151</li>
4152<li>
4153
4154<p>Special rules for GROUP BY:</p>
4155<ol style="list-style-type: decimal">
4156
4157<li>
4158
4159<p>If a GROUP BY clause specifies an expression that has no explicit alias, it binds a pseudo-variable that is lexicographically identical to the expression itself. For example:</p>
4160<p><tt>GROUP BY salary + bonus</tt> binds a pseudo-variable named <tt>salary + bonus</tt>.</p>
4161<p>This rule allows subsequent clauses to refer to the grouping expression (salary + bonus) even though its constituent variables (salary and bonus) are no longer in scope. For example, the following query is valid:</p>
4162
4163<div>
4164<div>
4165<pre class="source">FROM employee
4166GROUP BY salary + bonus
4167HAVING salary + bonus &gt; 1000
4168SELECT salary + bonus, COUNT(*) AS how_many
4169</pre></div></div>
4170
4171<p>While it might have been more elegant to explicitly require an alias in cases like this, the pseudo-variable rule is retained for SQL compatibility. Note that the expression <tt>salary + bonus</tt> is not <i>actually</i> evaluated in the HAVING and SELECT clauses (and could not be since <tt>salary</tt> and <tt>bonus</tt> are no longer individually in scope). Instead, the expression <tt>salary + bonus</tt> is treated as a reference to the pseudo-variable defined in the GROUP BY clause.</p>
4172</li>
4173<li>
4174
4175<p>A GROUP BY clause may be followed by a GROUP AS clause that binds a variable to the group. The purpose of this variable is to make the individual objects inside the group visible to subqueries that may need to iterate over them.</p>
4176<p>The GROUP AS variable is bound to a multiset of objects. Each object represents one of the members of the group. Since the group may have been formed from a join, each of the member-objects contains a nested object for each variable bound by the nearest FROM clause (and its LET subclause, if any). These nested objects, in turn, contain the actual fields of the group-member. To understand this process, consider the following query fragment:</p>
4177
4178<div>
4179<div>
4180<pre class="source">FROM parts AS p, suppliers AS s
4181WHERE p.suppno = s.suppno
4182GROUP BY p.color GROUP AS g
4183</pre></div></div>
4184
4185<p>Suppose that the objects in <tt>parts</tt> have fields <tt>partno</tt>, <tt>color</tt>, and <tt>suppno</tt>. Suppose that the objects in suppliers have fields <tt>suppno</tt> and <tt>location</tt>.</p>
4186<p>Then, for each group formed by the GROUP BY, the variable g will be bound to a multiset with the following structure:</p>
4187
4188<div>
4189<div>
4190<pre class="source">[ { &quot;p&quot;: { &quot;partno&quot;: &quot;p1&quot;, &quot;color&quot;: &quot;red&quot;, &quot;suppno&quot;: &quot;s1&quot; },
4191 &quot;s&quot;: { &quot;suppno&quot;: &quot;s1&quot;, &quot;location&quot;: &quot;Denver&quot; } },
4192 { &quot;p&quot;: { &quot;partno&quot;: &quot;p2&quot;, &quot;color&quot;: &quot;red&quot;, &quot;suppno&quot;: &quot;s2&quot; },
4193 &quot;s&quot;: { &quot;suppno&quot;: &quot;s2&quot;, &quot;location&quot;: &quot;Atlanta&quot; } },
4194 ...
4195]
4196</pre></div></div>
4197</li>
4198</ol>
4199</li>
4200</ol></div>
4201<div class="section">
4202<h2><a name="Scoping" id="Scoping">Scoping</a></h2>
4203<p>In general, the variables that are in scope at a particular position are those variables that were bound earlier in the current query block, in outer (enclosing) query blocks, or in a WITH clause at the beginning of the query. More specific rules follow.</p>
4204<p>The clauses in a query block are conceptually processed in the following order:</p>
4205<ul>
4206
4207<li>FROM (followed by LET subclause, if any)</li>
4208<li>WHERE</li>
4209<li>GROUP BY (followed by LET subclause, if any)</li>
4210<li>HAVING</li>
4211<li>SELECT or SELECT VALUE</li>
4212<li>ORDER BY</li>
4213<li>OFFSET</li>
4214<li>LIMIT</li>
4215</ul>
4216<p>During processing of each clause, the variables that are in scope are those variables that are bound in the following places:</p>
4217<ol style="list-style-type: decimal">
4218
4219<li>
4220
4221<p>In earlier clauses of the same query block (as defined by the ordering given above).</p>
4222<p>Example: <tt>FROM orders AS o SELECT o.date</tt> The variable <tt>o</tt> in the SELECT clause is bound, in turn, to each object in the dataset <tt>orders</tt>.</p>
4223</li>
4224<li>
4225
4226<p>In outer query blocks in which the current query block is nested. In case of duplication, the innermost binding wins.</p>
4227</li>
4228<li>
4229
4230<p>In the WITH clause (if any) at the beginning of the query.</p>
4231</li>
4232</ol>
4233<p>However, in a query block where a GROUP BY clause is present:</p>
4234<ol style="list-style-type: decimal">
4235
4236<li>
4237
4238<p>In clauses processed before GROUP BY, scoping rules are the same as though no GROUP BY were present.</p>
4239</li>
4240<li>
4241
4242<p>In clauses processed after GROUP BY, the variables bound in the nearest FROM-clause (and its LET subclause, if any) are removed from scope and replaced by the variables bound in the GROUP BY clause (and its LET subclause, if any). However, this replacement does not apply inside the arguments of the five SQL special aggregating functions (MIN, MAX, AVG, SUM, and COUNT). These functions still need to see the individual data items over which they are computing an aggregation. For example, after <tt>FROM employee AS e GROUP BY deptno</tt>, it would not be valid to reference <tt>e.salary</tt>, but <tt>AVG(e.salary)</tt> would be valid.</p>
4243</li>
4244</ol>
4245<p>Special case: In an expression inside a FROM clause, a variable is in scope if it was bound in an earlier expression in the same FROM clause. Example:</p>
4246
4247<div>
4248<div>
4249<pre class="source">FROM orders AS o, o.items AS i
4250</pre></div></div>
4251
4252<p>The reason for this special case is to support iteration over nested collections.</p>
4253<p>Note that, since the SELECT clause comes <i>after</i> the WHERE and GROUP BY clauses in conceptual processing order, any variables defined in SELECT are not visible in WHERE or GROUP BY. Therefore the following query will not return what might be the expected result (since in the WHERE clause, <tt>pay</tt> will be interpreted as a field in the <tt>emp</tt> object rather than as the computed value <tt>salary + bonus</tt>):</p>
4254
4255<div>
4256<div>
4257<pre class="source">SELECT name, salary + bonus AS pay
4258FROM emp
4259WHERE pay &gt; 1000
4260ORDER BY pay
4261</pre></div></div>
4262
4263<p>The likely intent of the query above can be accomplished as follows:</p>
4264
4265<div>
4266<div>
4267<pre class="source">FROM emp AS e
4268LET pay = e.salary + e.bonus
4269WHERE pay &gt; 1000
4270SELECT e.name, pay
4271ORDER BY pay
4272</pre></div></div>
4273
4274<p>Note that variables defined by <tt>JOIN</tt> subclauses are not visible to other subclauses in the same <tt>FROM</tt> clause. This also applies to the <tt>FROM</tt> variable that starts the <tt>JOIN</tt> subclause.</p></div>
4275<div class="section">
4276<h2><a name="Resolving_Names"></a><a name="Resolving_names" id="Resolving_names">Resolving Names</a></h2>
4277<p>The process of name resolution begins with the leftmost identifier in the name. The rules for resolving the leftmost identifier are:</p>
4278<ol style="list-style-type: decimal">
4279
4280<li>
4281
4282<p><i>In a FROM clause</i>: Names in a FROM clause identify the collections over which the query block will iterate. These collections may be stored datasets or may be the results of nested query blocks. A stored dataset may be in a named dataverse or in the default dataverse. Thus, if the two-part name <tt>a.b</tt> is in a FROM clause, a might represent a dataverse and <tt>b</tt> might represent a dataset in that dataverse. Another example of a two-part name in a FROM clause is <tt>FROM orders AS o, o.items AS i</tt>. In <tt>o.items</tt>, <tt>o</tt> represents an order object bound earlier in the FROM clause, and items represents the items object inside that order.</p>
4283<p>The rules for resolving the leftmost identifier in a FROM clause (including a JOIN subclause), or in the expression following IN in a quantified predicate, are as follows:</p>
4284<ol style="list-style-type: decimal">
4285
4286<li>
4287
4288<p>If the identifier matches a variable-name that is in scope, it resolves to the binding of that variable. (Note that in the case of a subquery, an in-scope variable might have been bound in an outer query block; this is called a correlated subquery.)</p>
4289</li>
4290<li>
4291
4292<p>Otherwise, if the identifier is the first part of a two-part name like <tt>a.b</tt>, the name is treated as dataverse.dataset. If the identifier stands alone as a one-part name, it is treated as the name of a dataset in the default dataverse. An error will result if the designated dataverse or dataset does not exist.</p>
4293</li>
4294</ol>
4295</li>
4296<li>
4297
4298<p><i>Elsewhere in a query block</i>: In clauses other than FROM, a name typically identifies a field of some object. For example, if the expression <tt>a.b</tt> is in a SELECT or WHERE clause, it&#x2019;s likely that <tt>a</tt> represents an object and <tt>b</tt> represents a field in that object.</p>
4299<p>The rules for resolving the leftmost identifier in clauses other than the ones listed in Rule 1 are:</p>
4300<ol style="list-style-type: decimal">
4301
4302<li>
4303
4304<p>If the identifier matches a variable-name that is in scope, it resolves to the binding of that variable. (In the case of a correlated subquery, the in-scope variable might have been bound in an outer query block.)</p>
4305</li>
4306<li>
4307
4308<p>(The &#x201c;Single Variable Rule&#x201d;): Otherwise, if the FROM clause (or a LET clause if there is no FROM clause) in the current query block binds exactly one variable, the identifier is treated as a field access on the object bound to that variable. For example, in the query <tt>FROM customer SELECT address</tt>, the identifier address is treated as a field in the object bound to the variable customer. At runtime, if the object bound to customer has no <tt>address</tt> field, the <tt>address</tt> expression will return <tt>missing</tt>. If the FROM clause (and its LET subclause, if any) in the current query block binds multiple variables, name resolution fails with an &#x201c;ambiguous name&#x201d; error. Note that the Single Variable Rule searches for bound variables only in the current query block, not in outer (containing) blocks. The purpose of this rule is to permit the compiler to resolve field-references unambiguously without relying on any schema information.</p>
4309<p>Exception: In a query that has a GROUP BY clause, the Single Variable Rule does not apply in any clauses that occur after the GROUP BY because, in these clauses, the variables bound by the FROM clause are no longer in scope. In clauses after GROUP BY, only Rule 2.1 applies.</p>
4310</li>
4311</ol>
4312</li>
4313<li>
4314
4315<p>In an ORDER BY clause following a UNION ALL expression:</p>
4316<p>The leftmost identifier is treated as a field-access on the objects that are generated by the UNION ALL. For example:</p>
4317
4318<div>
4319<div>
4320<pre class="source">query-block-1
4321UNION ALL
4322query-block-2
4323ORDER BY salary
4324</pre></div></div>
4325
4326<p>In the result of this query, objects that have a foo field will be ordered by the value of this field; objects that have no foo field will appear at at the beginning of the query result (in ascending order) or at the end (in descending order.)</p>
4327</li>
4328<li>
4329
4330<p>Once the leftmost identifier has been resolved, the following dots and identifiers in the name (if any) are treated as a path expression that navigates to a field nested inside that object. The name resolves to the field at the end of the path. If this field does not exist, the value <tt>missing</tt> is returned.</p>
4331</li>
4332</ol></div>
4333 </div>
4334 </div>
4335 </div>
4336 <hr/>
4337 <footer>
4338 <div class="container-fluid">
4339 <div class="row-fluid">
4340<div class="row-fluid">Apache AsterixDB, AsterixDB, Apache, the Apache
4341 feather logo, and the Apache AsterixDB project logo are either
4342 registered trademarks or trademarks of The Apache Software
4343 Foundation in the United States and other countries.
4344 All other marks mentioned may be trademarks or registered
4345 trademarks of their respective owners.
4346 </div>
4347 </div>
4348 </div>
4349 </footer>
4350 </body>
4351</html>