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