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