blob: 845214fa67c3c3a88eb9dc243fc464beb9a43cbf [file] [log] [blame]
<!DOCTYPE html>
<!--
| Generated by Apache Maven Doxia at 2017-01-25
| Rendered using Apache Maven Fluido Skin 1.3.0
-->
<html xmlns="http://www.w3.org/1999/xhtml" xml:lang="en" lang="en">
<head>
<meta charset="UTF-8" />
<meta name="viewport" content="width=device-width, initial-scale=1.0" />
<meta name="Date-Revision-yyyymmdd" content="20170125" />
<meta http-equiv="Content-Language" content="en" />
<title>AsterixDB &#x2013; The SQL++ Query Language</title>
<link rel="stylesheet" href="../css/apache-maven-fluido-1.3.0.min.css" />
<link rel="stylesheet" href="../css/site.css" />
<link rel="stylesheet" href="../css/print.css" media="print" />
<script type="text/javascript" src="../js/apache-maven-fluido-1.3.0.min.js"></script>
<script>(function(i,s,o,g,r,a,m){i['GoogleAnalyticsObject']=r;i[r]=i[r]||function(){
(i[r].q=i[r].q||[]).push(arguments)},i[r].l=1*new Date();a=s.createElement(o),
m=s.getElementsByTagName(o)[0];a.async=1;a.src=g;m.parentNode.insertBefore(a,m)
})(window,document,'script','//www.google-analytics.com/analytics.js','ga');
ga('create', 'UA-41536543-1', 'uci.edu');
ga('send', 'pageview');</script>
</head>
<body class="topBarDisabled">
<div class="container-fluid">
<div id="banner">
<div class="pull-left">
<a href=".././" id="bannerLeft">
<img src="../images/asterixlogo.png" alt="AsterixDB"/>
</a>
</div>
<div class="pull-right"> </div>
<div class="clear"><hr/></div>
</div>
<div id="breadcrumbs">
<ul class="breadcrumb">
<li id="publishDate">Last Published: 2017-01-25</li>
<li id="projectVersion" class="pull-right">Version: 0.9.0</li>
<li class="divider pull-right">|</li>
<li class="pull-right"> <a href="../index.html" title="Documentation Home">
Documentation Home</a>
</li>
</ul>
</div>
<div class="row-fluid">
<div id="leftColumn" class="span3">
<div class="well sidebar-nav">
<ul class="nav nav-list">
<li class="nav-header">Get Started - Installation</li>
<li>
<a href="../ncservice.html" title="Option 1: using NCService">
<i class="none"></i>
Option 1: using NCService</a>
</li>
<li>
<a href="../install.html" title="Option 2: using Managix">
<i class="none"></i>
Option 2: using Managix</a>
</li>
<li>
<a href="../yarn.html" title="Option 3: using YARN">
<i class="none"></i>
Option 3: using YARN</a>
</li>
<li class="nav-header">AsterixDB Primer</li>
<li>
<a href="../sqlpp/primer-sqlpp.html" title="Option 1: using SQL++">
<i class="none"></i>
Option 1: using SQL++</a>
</li>
<li>
<a href="../aql/primer.html" title="Option 2: using AQL">
<i class="none"></i>
Option 2: using AQL</a>
</li>
<li class="nav-header">Data Model</li>
<li>
<a href="../datamodel.html" title="The Asterix Data Model">
<i class="none"></i>
The Asterix Data Model</a>
</li>
<li class="nav-header">Queries - SQL++</li>
<li class="active">
<a href="#"><i class="none"></i>The SQL++ Query Language</a>
</li>
<li>
<a href="../sqlpp/builtins.html" title="Builtin Functions">
<i class="none"></i>
Builtin Functions</a>
</li>
<li class="nav-header">Queries - AQL</li>
<li>
<a href="../aql/manual.html" title="The Asterix Query Language (AQL)">
<i class="none"></i>
The Asterix Query Language (AQL)</a>
</li>
<li>
<a href="../aql/builtins.html" title="Builtin Functions">
<i class="none"></i>
Builtin Functions</a>
</li>
<li class="nav-header">Advanced Features</li>
<li>
<a href="../aql/similarity.html" title="Support of Similarity Queries">
<i class="none"></i>
Support of Similarity Queries</a>
</li>
<li>
<a href="../aql/fulltext.html" title="Support of Full-text Queries">
<i class="none"></i>
Support of Full-text Queries</a>
</li>
<li>
<a href="../aql/externaldata.html" title="Accessing External Data">
<i class="none"></i>
Accessing External Data</a>
</li>
<li>
<a href="../feeds/tutorial.html" title="Support for Data Ingestion">
<i class="none"></i>
Support for Data Ingestion</a>
</li>
<li>
<a href="../udf.html" title="User Defined Functions">
<i class="none"></i>
User Defined Functions</a>
</li>
<li>
<a href="../aql/filters.html" title="Filter-Based LSM Index Acceleration">
<i class="none"></i>
Filter-Based LSM Index Acceleration</a>
</li>
<li class="nav-header">API/SDK</li>
<li>
<a href="../api.html" title="HTTP API">
<i class="none"></i>
HTTP API</a>
</li>
</ul>
<hr class="divider" />
<div id="poweredBy">
<div class="clear"></div>
<div class="clear"></div>
<div class="clear"></div>
<a href=".././" title="AsterixDB" class="builtBy">
<img class="builtBy" alt="AsterixDB" src="../images/asterixlogo.png" />
</a>
</div>
</div>
</div>
<div id="bodyColumn" class="span9" >
<!-- ! Licensed to the Apache Software Foundation (ASF) under one
! or more contributor license agreements. See the NOTICE file
! distributed with this work for additional information
! regarding copyright ownership. The ASF licenses this file
! to you under the Apache License, Version 2.0 (the
! "License"); you may not use this file except in compliance
! with the License. You may obtain a copy of the License at
!
! http://www.apache.org/licenses/LICENSE-2.0
!
! Unless required by applicable law or agreed to in writing,
! software distributed under the License is distributed on an
! "AS IS" BASIS, WITHOUT WARRANTIES OR CONDITIONS OF ANY
! KIND, either express or implied. See the License for the
! specific language governing permissions and limitations
! under the License.
! --><h1>The SQL++ Query Language</h1>
<div class="section">
<h2><a name="Table_of_Contents"></a><a name="toc" id="toc">Table of Contents</a></h2>
<ul>
<li><a href="#Introduction">1. Introduction</a></li>
<li><a href="#Expressions">2. Expressions</a>
<ul>
<li><a href="#Operator_expressions">Operator expressions</a>
<ul>
<li><a href="#Arithmetic_operators">Arithmetic operators</a></li>
<li><a href="#Collection_operators">Collection operators</a></li>
<li><a href="#Comparison_operators">Comparison operators</a></li>
<li><a href="#Logical_operators">Logical operators</a></li>
</ul></li>
<li><a href="#Case_expressions">Case expressions</a></li>
<li><a href="#Quantified_expressions">Quantified expressions</a></li>
<li><a href="#Path_expressions">Path expressions</a></li>
<li><a href="#Primary_expressions">Primary expressions</a>
<ul>
<li><a href="#Literals">Literals</a></li>
<li><a href="#Variable_references">Variable references</a></li>
<li><a href="#Parenthesized_expressions">Parenthesized expressions</a></li>
<li><a href="#Function_call_expressions">Function call expressions</a></li>
<li><a href="#Constructors">Constructors</a></li>
</ul></li>
</ul></li>
<li><a href="#Queries">3. Queries</a>
<ul>
<li><a href="#SELECT_statements">SELECT statements</a></li>
<li><a href="#Select_clauses">SELECT clauses</a>
<ul>
<li><a href="#Select_element">Select element/value/raw</a></li>
<li><a href="#SQL_select">SQL-style select</a></li>
<li><a href="#Select_star">Select *</a></li>
<li><a href="#Select_distinct">Select distinct</a></li>
<li><a href="#Unnamed_projections">Unnamed projections</a></li>
<li><a href="#Abbreviatory_field_access_expressions">Abbreviatory field access expressions</a></li>
</ul></li>
<li><a href="#Unnest_clauses">UNNEST clauses</a>
<ul>
<li><a href="#Inner_unnests">Inner unnests</a></li>
<li><a href="#Left_outer_unnests">Left outer unnests</a></li>
<li><a href="#Expressing_joins_using_unnests">Expressing joins using unnests</a></li>
</ul></li>
<li><a href="#From_clauses">FROM clauses</a>
<ul>
<li><a href="#Binding_expressions">Binding expressions</a></li>
<li><a href="#Multiple_from_terms">Multiple from terms</a></li>
<li><a href="#Expressing_joins_using_from_terms">Expressing joins using from terms</a></li>
<li><a href="#Implicit_binding_variables">Implicit binding variables</a></li>
</ul></li>
<li><a href="#Join_clauses">JOIN clauses</a>
<ul>
<li><a href="#Inner_joins">Inner joins</a></li>
<li><a href="#Left_outer_joins">Left outer joins</a></li>
</ul></li>
<li><a href="#Group_By_clauses">GROUP BY clauses</a>
<ul>
<li><a href="#Group_variables">Group variables</a></li>
<li><a href="#Implicit_group_key_variables">Implicit group key variables</a></li>
<li><a href="#Implicit_group_variables">Implicit group variables</a></li>
<li><a href="#Aggregation_functions">Aggregation functions</a></li>
<li><a href="#SQL-92_aggregation_functions">SQL-92 aggregation functions</a></li>
<li><a href="#SQL-92_compliant_gby">SQL-92 compliant GROUP BY aggregations</a></li>
<li><a href="#Column_aliases">Column aliases</a></li>
</ul></li>
<li><a href="#Where_having_clauses">WHERE clauases and HAVING clauses</a></li>
<li><a href="#Order_By_clauses">ORDER BY clauses</a></li>
<li><a href="#Limit_clauses">LIMIT clauses</a></li>
<li><a href="#With_clauses">WITH clauses</a></li>
<li><a href="#Let_clauses">LET clauses</a></li>
<li><a href="#Union_all">UNION ALL</a></li>
<li><a href="#Vs_SQL-92">SQL++ Vs. SQL-92</a></li>
</ul></li>
<li><a href="#Errors">4. Errors</a>
<ul>
<li><a href="#Syntax_errors">Syntax errors</a></li>
<li><a href="#Parsing_errors">Identifier resolution errors</a></li>
<li><a href="#Type_errors">Type errors</a></li>
<li><a href="#Resource_errors">Resource errors</a></li>
</ul></li>
<li><a href="#DDL_and_DML_statements">5. DDL and DML statements</a>
<ul>
<li><a href="#Declarations">Declarations</a></li>
<li><a href="#Lifecycle_management_statements">Lifecycle management statements</a>
<ul>
<li><a href="#Dataverses">Dataverses</a></li>
<li><a href="#Datasets">Datasets</a></li>
<li><a href="#Types">Types</a></li>
<li><a href="#Functions">Functions</a></li>
</ul></li>
<li><a href="#Modification_statements">Modification statements</a>
<ul>
<li><a href="#Inserts">Inserts</a></li>
<li><a href="#Upserts">Upserts</a></li>
<li><a href="#Deletes">Deletes</a></li>
</ul></li>
</ul></li>
<li><a href="#Reserved_keywords">Appendix 1. Reserved keywords</a></li>
</ul>
<!-- ! Licensed to the Apache Software Foundation (ASF) under one
! or more contributor license agreements. See the NOTICE file
! distributed with this work for additional information
! regarding copyright ownership. The ASF licenses this file
! to you under the Apache License, Version 2.0 (the
! "License"); you may not use this file except in compliance
! with the License. You may obtain a copy of the License at
!
! http://www.apache.org/licenses/LICENSE-2.0
!
! Unless required by applicable law or agreed to in writing,
! software distributed under the License is distributed on an
! "AS IS" BASIS, WITHOUT WARRANTIES OR CONDITIONS OF ANY
! KIND, either express or implied. See the License for the
! specific language governing permissions and limitations
! under the License.
! -->
<h1><a name="Introduction" id="Introduction">1. Introduction</a><font size="3" /></h1>
<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>
<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>
<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>
<!-- ! Licensed to the Apache Software Foundation (ASF) under one
! or more contributor license agreements. See the NOTICE file
! distributed with this work for additional information
! regarding copyright ownership. The ASF licenses this file
! to you under the Apache License, Version 2.0 (the
! "License"); you may not use this file except in compliance
! with the License. You may obtain a copy of the License at
!
! http://www.apache.org/licenses/LICENSE-2.0
!
! Unless required by applicable law or agreed to in writing,
! software distributed under the License is distributed on an
! "AS IS" BASIS, WITHOUT WARRANTIES OR CONDITIONS OF ANY
! KIND, either express or implied. See the License for the
! specific language governing permissions and limitations
! under the License.
! -->
<h1><a name="Expressions" id="Expressions">2. Expressions</a></h1>
<div class="source">
<div class="source">
<pre>Expression ::= OperatorExpression | CaseExpression | QuantifiedExpression
</pre></div></div>
<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>
<p>Note that in the following text, words enclosed in angle brackets denote keywords that are not case-sensitive.</p></div>
<div class="section">
<h2><a name="Operator_expressions" id="Operator_expressions">Operator expressions</a></h2>
<p>Operators perform a specific operation on the input values or expressions. The syntax of an operator expression is as follows:</p>
<div class="source">
<div class="source">
<pre>OperatorExpression ::= PathExpression
| Operator OperatorExpression
| OperatorExpression Operator (OperatorExpression)?
| OperatorExpression &lt;BETWEEN&gt; OperatorExpression &lt;AND&gt; OperatorExpression
</pre></div></div>
<p>SQL++ provides a full set of operators that you can use within its statements. Here are the categories of operators:</p>
<ul>
<li><a href="#Arithmetic_operators">Arithmetic operators</a>, to perform basic mathematical operations;</li>
<li><a href="#Collection_operators">Collection operators</a>, to evaluate expressions on collections or objects;</li>
<li><a href="#Comparison_operators">Comparison operators</a>, to compare two expressions;</li>
<li><a href="#Logical_operators">Logical Operators</a>, to combine operators using Boolean logic.</li>
</ul>
<p>The following table summarizes the precedence order (from higher to lower) of the major unary and binary operators:</p>
<table border="0" class="table table-striped">
<thead>
<tr class="a">
<th>Operator </th>
<th>Operation </th>
</tr>
</thead>
<tbody>
<tr class="b">
<td>EXISTS, NOT EXISTS </td>
<td>collection emptiness testing </td>
</tr>
<tr class="a">
<td>^ </td>
<td>exponentiation </td>
</tr>
<tr class="b">
<td>*, /, % </td>
<td>multiplication, division, modulo </td>
</tr>
<tr class="a">
<td>+, - </td>
<td>addition, subtraction </td>
</tr>
<tr class="b">
<td>|| </td>
<td>string concatenation </td>
</tr>
<tr class="a">
<td>IS NULL, IS NOT NULL, IS MISSING, IS NOT MISSING, <br />IS UNKNOWN, IS NOT UNKNOWN</td>
<td>unknown value comparison </td>
</tr>
<tr class="b">
<td>BETWEEN, NOT BETWEEN </td>
<td>range comparison (inclusive on both sides) </td>
</tr>
<tr class="a">
<td>=, !=, &lt;, &gt;, &lt;=, &gt;=, LIKE, NOT LIKE, IN, NOT IN </td>
<td>comparison </td>
</tr>
<tr class="b">
<td>NOT </td>
<td>logical negation </td>
</tr>
<tr class="a">
<td>AND </td>
<td>conjunction </td>
</tr>
<tr class="b">
<td>OR </td>
<td>disjunction </td>
</tr>
</tbody>
</table>
<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 encolosing 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>
<div class="section">
<h3><a name="Arithmetic_operators" id="Arithmetic_operators">Arithmetic operators</a></h3>
<p>Arithemtic operators are used to exponentiate, add, subtract, multiply, and divide numeric values, or concatenate string values.</p>
<table border="0" class="table table-striped">
<thead>
<tr class="a">
<th>Operator </th>
<th>Purpose </th>
<th>Example </th>
</tr>
</thead>
<tbody>
<tr class="b">
<td>+, - </td>
<td>As unary operators, they denote a <br />positive or negative expression </td>
<td>SELECT VALUE -1; </td>
</tr>
<tr class="a">
<td>+, - </td>
<td>As binary operators, they add or subtract </td>
<td>SELECT VALUE 1 + 2; </td>
</tr>
<tr class="b">
<td>*, / </td>
<td>Multiply, divide </td>
<td>SELECT VALUE 4 / 2.0; </td>
</tr>
<tr class="a">
<td>^ </td>
<td>Exponentiation </td>
<td>SELECT VALUE 2^3; </td>
</tr>
<tr class="b">
<td>|| </td>
<td>String concatenation </td>
<td>SELECT VALUE &#x201c;ab&#x201d;||&#x201c;c&#x201d;||&#x201c;d&#x201d;; </td>
</tr>
</tbody>
</table></div>
<div class="section">
<h3><a name="Collection_operators" id="Collection_operators">Collection operators</a></h3>
<p>Collection operators are used for membership tests (IN, NOT IN) or empty collection tests (EXISTS, NOT EXISTS).</p>
<table border="0" class="table table-striped">
<thead>
<tr class="a">
<th>Operator </th>
<th>Purpose </th>
<th>Example </th>
</tr>
</thead>
<tbody>
<tr class="b">
<td>IN </td>
<td>Membership test </td>
<td>SELECT * FROM ChirpMessages cm <br />WHERE cm.user.lang IN [&#x201c;en&#x201d;, &#x201c;de&#x201d;]; </td>
</tr>
<tr class="a">
<td>NOT IN </td>
<td>Non-membership test </td>
<td>SELECT * FROM ChirpMessages cm <br />WHERE cm.user.lang NOT IN [&#x201c;en&#x201d;]; </td>
</tr>
<tr class="b">
<td>EXISTS </td>
<td>Check whether a collection is not empty </td>
<td>SELECT * FROM ChirpMessages cm <br />WHERE EXISTS cm.referredTopics; </td>
</tr>
<tr class="a">
<td>NOT EXISTS </td>
<td>Check whether a collection is empty </td>
<td>SELECT * FROM ChirpMessages cm <br />WHERE NOT EXISTS cm.referredTopics; </td>
</tr>
</tbody>
</table></div>
<div class="section">
<h3><a name="Comparison_operators" id="Comparison_operators">Comparison operators</a></h3>
<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>
<div class="section">
<div class="section">
<h5><a name="Examples"></a>Examples</h5>
<p>{&#x201c;name&#x201d;: &#x201c;Jack&#x201d;, &#x201c;friend&#x201d;: &#x201c;Jill&#x201d;}</p>
<p>{&#x201c;name&#x201d;: &#x201c;Jake&#x201d;, &#x201c;friend&#x201d;: NULL}</p>
<p>{&#x201c;name&#x201d;: &#x201c;Joe&#x201d;}</p>
<p>The following table enumerates all of SQL++&#x2019;s comparison operators.</p>
<table border="0" class="table table-striped">
<thead>
<tr class="a">
<th>Operator </th>
<th>Purpose </th>
<th>Example </th>
</tr>
</thead>
<tbody>
<tr class="b">
<td>IS NULL </td>
<td>Test if a value is NULL </td>
<td>SELECT * FROM ChirpMessages cm <br />WHERE cm.user.name IS NULL; </td>
</tr>
<tr class="a">
<td>IS NOT NULL </td>
<td>Test if a value is not NULL </td>
<td>SELECT * FROM ChirpMessages cm <br />WHERE cm.user.name IS NOT NULL; </td>
</tr>
<tr class="b">
<td>IS MISSING </td>
<td>Test if a value is MISSING </td>
<td>SELECT * FROM ChirpMessages cm <br />WHERE cm.user.name IS MISSING; </td>
</tr>
<tr class="a">
<td>IS NOT MISSING </td>
<td>Test if a value is not MISSING </td>
<td>SELECT * FROM ChirpMessages cm <br />WHERE cm.user.name IS NOT MISSING;</td>
</tr>
<tr class="b">
<td>IS UNKNOWN </td>
<td>Test if a value is NULL or MISSING </td>
<td>SELECT * FROM ChirpMessages cm <br />WHERE cm.user.name IS UNKNOWN; </td>
</tr>
<tr class="a">
<td>IS NOT UNKNOWN </td>
<td>Test if a value is neither NULL nor MISSING </td>
<td>SELECT * FROM ChirpMessages cm <br />WHERE cm.user.name IS NOT UNKNOWN;</td>
</tr>
<tr class="b">
<td>BETWEEN </td>
<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>
<td>SELECT * FROM ChirpMessages cm <br />WHERE cm.chirpId BETWEEN 10 AND 20;</td>
</tr>
<tr class="a">
<td>= </td>
<td>Equality test </td>
<td>SELECT * FROM ChirpMessages cm <br />WHERE cm.chirpId=10; </td>
</tr>
<tr class="b">
<td>!= </td>
<td>Inequality test </td>
<td>SELECT * FROM ChirpMessages cm <br />WHERE cm.chirpId!=10;</td>
</tr>
<tr class="a">
<td>&lt; </td>
<td>Less than </td>
<td>SELECT * FROM ChirpMessages cm <br />WHERE cm.chirpId&lt;10; </td>
</tr>
<tr class="b">
<td>&gt; </td>
<td>Greater than </td>
<td>SELECT * FROM ChirpMessages cm <br />WHERE cm.chirpId&gt;10; </td>
</tr>
<tr class="a">
<td>&lt;= </td>
<td>Less than or equal to </td>
<td>SELECT * FROM ChirpMessages cm <br />WHERE cm.chirpId&lt;=10; </td>
</tr>
<tr class="b">
<td>&gt;= </td>
<td>Greater than or equal to </td>
<td>SELECT * FROM ChirpMessages cm <br />WHERE cm.chirpId&gt;=10; </td>
</tr>
<tr class="a">
<td>LIKE </td>
<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>
<td>SELECT * FROM ChirpMessages cm <br />WHERE cm.user.name LIKE &#x201c;%Giesen%&#x201d;;</td>
</tr>
<tr class="b">
<td>NOT LIKE </td>
<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>
<td>SELECT * FROM ChirpMessages cm <br />WHERE cm.user.name NOT LIKE &#x201c;%Giesen%&#x201d;;</td>
</tr>
</tbody>
</table>
<p>The following table summarizes how the missing value comparison operators work.</p>
<table border="0" class="table table-striped">
<thead>
<tr class="a">
<th>Operator </th>
<th>Non-NULL/Non-MISSING value </th>
<th>NULL </th>
<th>MISSING </th>
</tr>
</thead>
<tbody>
<tr class="b">
<td>IS NULL </td>
<td>FALSE </td>
<td>TRUE </td>
<td>MISSING </td>
</tr>
<tr class="a">
<td>IS NOT NULL </td>
<td>TRUE </td>
<td>FALSE </td>
<td>MISSING </td>
</tr>
<tr class="b">
<td>IS MISSING </td>
<td>FALSE </td>
<td>FALSE </td>
<td>TRUE </td>
</tr>
<tr class="a">
<td>IS NOT MISSING </td>
<td>TRUE </td>
<td>TRUE </td>
<td>FALSE </td>
</tr>
<tr class="b">
<td>IS UNKNOWN </td>
<td>FALSE </td>
<td>TRUE </td>
<td>TRUE </td>
</tr>
<tr class="a">
<td>IS NOT UNKNOWN </td>
<td>TRUE </td>
<td>FALSE </td>
<td>FALSE</td>
</tr>
</tbody>
</table></div></div></div>
<div class="section">
<h3><a name="Logical_operators" id="Logical_operators">Logical operators</a></h3>
<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>
<table border="0" class="table table-striped">
<thead>
<tr class="a">
<th>Operator </th>
<th>Purpose </th>
<th>Example </th>
</tr>
</thead>
<tbody>
<tr class="b">
<td>NOT </td>
<td>Returns true if the following condition is false, otherwise returns false </td>
<td>SELECT VALUE NOT TRUE; </td>
</tr>
<tr class="a">
<td>AND </td>
<td>Returns true if both branches are true, otherwise returns false </td>
<td>SELECT VALUE TRUE AND FALSE; </td>
</tr>
<tr class="b">
<td>OR </td>
<td>Returns true if one branch is true, otherwise returns false </td>
<td>SELECT VALUE FALSE OR FALSE; </td>
</tr>
</tbody>
</table>
<p>The following table is the truth table for <tt>AND</tt> and <tt>OR</tt>.</p>
<table border="0" class="table table-striped">
<thead>
<tr class="a">
<th>A </th>
<th>B </th>
<th>A AND B </th>
<th>A OR B </th>
</tr>
</thead>
<tbody>
<tr class="b">
<td>TRUE </td>
<td>TRUE </td>
<td>TRUE </td>
<td>TRUE </td>
</tr>
<tr class="a">
<td>TRUE </td>
<td>FALSE </td>
<td>FALSE </td>
<td>TRUE </td>
</tr>
<tr class="b">
<td>TRUE </td>
<td>NULL </td>
<td>NULL </td>
<td>TRUE </td>
</tr>
<tr class="a">
<td>TRUE </td>
<td>MISSING </td>
<td>MISSING </td>
<td>TRUE </td>
</tr>
<tr class="b">
<td>FALSE </td>
<td>FALSE </td>
<td>FALSE </td>
<td>FALSE </td>
</tr>
<tr class="a">
<td>FALSE </td>
<td>NULL </td>
<td>FALSE </td>
<td>NULL </td>
</tr>
<tr class="b">
<td>FALSE </td>
<td>MISSING </td>
<td>FALSE </td>
<td>MISSING </td>
</tr>
<tr class="a">
<td>NULL </td>
<td>NULL </td>
<td>NULL </td>
<td>NULL </td>
</tr>
<tr class="b">
<td>NULL </td>
<td>MISSING </td>
<td>MISSING </td>
<td>NULL </td>
</tr>
<tr class="a">
<td>MISSING </td>
<td>MISSING </td>
<td>MISSING </td>
<td>MISSING </td>
</tr>
</tbody>
</table>
<p>The following table demonstrates the results of <tt>NOT</tt> on all possible inputs.</p>
<table border="0" class="table table-striped">
<thead>
<tr class="a">
<th>A </th>
<th>NOT A </th>
</tr>
</thead>
<tbody>
<tr class="b">
<td>TRUE </td>
<td>FALSE </td>
</tr>
<tr class="a">
<td>FALSE </td>
<td>TRUE </td>
</tr>
<tr class="b">
<td>NULL </td>
<td>NULL </td>
</tr>
<tr class="a">
<td>MISSING </td>
<td>MISSING </td>
</tr>
</tbody>
</table></div></div>
<div class="section">
<h2><a name="Case_expressions" id="Case_expressions">Case expressions</a></h2>
<div class="source">
<div class="source">
<pre>CaseExpression ::= SimpleCaseExpression | SearchedCaseExpression
SimpleCaseExpression ::= &lt;CASE&gt; Expression ( &lt;WHEN&gt; Expression &lt;THEN&gt; Expression )+ ( &lt;ELSE&gt; Expression )? &lt;END&gt;
SearchedCaseExpression ::= &lt;CASE&gt; ( &lt;WHEN&gt; Expression &lt;THEN&gt; Expression )+ ( &lt;ELSE&gt; Expression )? &lt;END&gt;
</pre></div></div>
<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>
<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>
<p>The following example illustrates the form of a case expression.</p>
<div class="section">
<div class="section">
<div class="section">
<h5><a name="Example"></a>Example</h5>
<div class="source">
<div class="source">
<pre>CASE (2 &lt; 3) WHEN true THEN &quot;yes&quot; ELSE &quot;no&quot; END
</pre></div></div></div></div></div></div>
<div class="section">
<h2><a name="Quantified_expressions" id="Quantified_expressions">Quantified expressions</a></h2>
<div class="source">
<div class="source">
<pre>QuantifiedExpression ::= ( (&lt;ANY&gt;|&lt;SOME&gt;) | &lt;EVERY&gt; ) Variable &lt;IN&gt; Expression ( &quot;,&quot; Variable &quot;in&quot; Expression )*
&lt;SATISFIES&gt; Expression (&lt;END&gt;)?
</pre></div></div>
<p>Quantified expressions are used for expressing existential or universal predicates involving the elements of a collection.</p>
<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>
<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>
<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>
<div class="section">
<div class="section">
<div class="section">
<h5><a name="Examples"></a>Examples</h5>
<div class="source">
<div class="source">
<pre>EVERY x IN [ 1, 2, 3 ] SATISFIES x &lt; 3
SOME x IN [ 1, 2, 3 ] SATISFIES x &lt; 3
</pre></div></div></div></div></div></div>
<div class="section">
<h2><a name="Path_expressions" id="Path_expressions">Path expressions</a></h2>
<div class="source">
<div class="source">
<pre>PathExpression ::= PrimaryExpression ( Field | Index )*
Field ::= &quot;.&quot; Identifier
Index ::= &quot;[&quot; ( Expression | &quot;?&quot; ) &quot;]&quot;
</pre></div></div>
<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, e.g., 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>
<p>The following examples illustrate field access for a object, index-based element access for an array, and also a composition thereof.</p>
<div class="section">
<div class="section">
<div class="section">
<h5><a name="Examples"></a>Examples</h5>
<div class="source">
<div class="source">
<pre>({&quot;name&quot;: &quot;MyABCs&quot;, &quot;array&quot;: [ &quot;a&quot;, &quot;b&quot;, &quot;c&quot;]}).array
([&quot;a&quot;, &quot;b&quot;, &quot;c&quot;])[2]
({&quot;name&quot;: &quot;MyABCs&quot;, &quot;array&quot;: [ &quot;a&quot;, &quot;b&quot;, &quot;c&quot;]}).array[2]
</pre></div></div></div></div></div></div>
<div class="section">
<h2><a name="Primary_Expressions"></a><a name="Primary_expressions" id="Primary_expressions">Primary Expressions</a></h2>
<div class="source">
<div class="source">
<pre>PrimaryExpr ::= Literal
| VariableReference
| ParenthesizedExpression
| FunctionCallExpression
| Constructor
</pre></div></div>
<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 class="section">
<h3><a name="Literals" id="Literals">Literals</a></h3>
<div class="source">
<div class="source">
<pre>Literal ::= StringLiteral
| IntegerLiteral
| FloatLiteral
| DoubleLiteral
| &lt;NULL&gt;
| &lt;MISSING&gt;
| &lt;TRUE&gt;
| &lt;FALSE&gt;
StringLiteral ::= &quot;\&quot;&quot; (
&lt;EscapeQuot&gt;
| &lt;EscapeBslash&gt;
| &lt;EscapeSlash&gt;
| &lt;EscapeBspace&gt;
| &lt;EscapeFormf&gt;
| &lt;EscapeNl&gt;
| &lt;EscapeCr&gt;
| &lt;EscapeTab&gt;
| ~[&quot;\&quot;&quot;,&quot;\\&quot;])*
&quot;\&quot;&quot;
| &quot;\'&quot;(
&lt;EscapeApos&gt;
| &lt;EscapeBslash&gt;
| &lt;EscapeSlash&gt;
| &lt;EscapeBspace&gt;
| &lt;EscapeFormf&gt;
| &lt;EscapeNl&gt;
| &lt;EscapeCr&gt;
| &lt;EscapeTab&gt;
| ~[&quot;\'&quot;,&quot;\\&quot;])*
&quot;\'&quot;
&lt;ESCAPE_Apos&gt; ::= &quot;\\\'&quot;
&lt;ESCAPE_Quot&gt; ::= &quot;\\\&quot;&quot;
&lt;EscapeBslash&gt; ::= &quot;\\\\&quot;
&lt;EscapeSlash&gt; ::= &quot;\\/&quot;
&lt;EscapeBspace&gt; ::= &quot;\\b&quot;
&lt;EscapeFormf&gt; ::= &quot;\\f&quot;
&lt;EscapeNl&gt; ::= &quot;\\n&quot;
&lt;EscapeCr&gt; ::= &quot;\\r&quot;
&lt;EscapeTab&gt; ::= &quot;\\t&quot;
IntegerLiteral ::= &lt;DIGITS&gt;
&lt;DIGITS&gt; ::= [&quot;0&quot; - &quot;9&quot;]+
FloatLiteral ::= &lt;DIGITS&gt; ( &quot;f&quot; | &quot;F&quot; )
| &lt;DIGITS&gt; ( &quot;.&quot; &lt;DIGITS&gt; ( &quot;f&quot; | &quot;F&quot; ) )?
| &quot;.&quot; &lt;DIGITS&gt; ( &quot;f&quot; | &quot;F&quot; )
DoubleLiteral ::= &lt;DIGITS&gt; &quot;.&quot; &lt;DIGITS&gt;
| &quot;.&quot; &lt;DIGITS&gt;
</pre></div></div>
<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>
<p>The following are some simple examples of SQL++ literals.</p>
<div class="section">
<div class="section">
<h5><a name="Examples"></a>Examples</h5>
<div class="source">
<div class="source">
<pre>'a string'
&quot;test string&quot;
42
</pre></div></div>
<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>
<div class="section">
<h3><a name="Variable_References"></a><a name="Variable_references" id="Variable_references">Variable References</a></h3>
<div class="source">
<div class="source">
<pre>VariableReference ::= &lt;IDENTIFIER&gt;|&lt;DelimitedIdentifier&gt;
&lt;IDENTIFIER&gt; ::= &lt;LETTER&gt; (&lt;LETTER&gt; | &lt;DIGIT&gt; | &quot;_&quot; | &quot;$&quot;)*
&lt;LETTER&gt; ::= [&quot;A&quot; - &quot;Z&quot;, &quot;a&quot; - &quot;z&quot;]
DelimitedIdentifier ::= &quot;`&quot; (&lt;EscapeQuot&gt;
| &lt;EscapeBslash&gt;
| &lt;EscapeSlash&gt;
| &lt;EscapeBspace&gt;
| &lt;EscapeFormf&gt;
| &lt;EscapeNl&gt;
| &lt;EscapeCr&gt;
| &lt;EscapeTab&gt;
| ~[&quot;`&quot;,&quot;\\&quot;])*
&quot;`&quot;
</pre></div></div>
<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, e.g., `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>
<div class="section">
<div class="section">
<h5><a name="Examples"></a>Examples</h5>
<div class="source">
<div class="source">
<pre>tweet
id
`SELECT`
`my-function`
</pre></div></div></div></div></div>
<div class="section">
<h3><a name="Parenthesized_expressions" id="Parenthesized_expressions">Parenthesized expressions</a></h3>
<div class="source">
<div class="source">
<pre>ParenthesizedExpression ::= &quot;(&quot; Expression &quot;)&quot; | Subquery
</pre></div></div>
<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>
<p>The following expression evaluates to the value 2.</p>
<div class="section">
<div class="section">
<h5><a name="Example"></a>Example</h5>
<div class="source">
<div class="source">
<pre>( 1 + 1 )
</pre></div></div></div></div></div>
<div class="section">
<h3><a name="Function_call_expressions" id="Function_call_expressions">Function call expressions</a></h3>
<div class="source">
<div class="source">
<pre>FunctionCallExpression ::= FunctionName &quot;(&quot; ( Expression ( &quot;,&quot; Expression )* )? &quot;)&quot;
</pre></div></div>
<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>
<p>The following example is a (built-in) function call expression whose value is 8.</p>
<div class="section">
<div class="section">
<h5><a name="Example"></a>Example</h5>
<div class="source">
<div class="source">
<pre>length('a string')
</pre></div></div></div></div></div>
<div class="section">
<h3><a name="Constructors" id="Constructors">Constructors</a></h3>
<div class="source">
<div class="source">
<pre>Constructor ::= ArrayConstructor | MultisetConstructor | ObjectConstructor
ArrayConstructor ::= &quot;[&quot; ( Expression ( &quot;,&quot; Expression )* )? &quot;]&quot;
MultisetConstructor ::= &quot;{{&quot; ( Expression ( &quot;,&quot; Expression )* )? &quot;}}&quot;
ObjectConstructor ::= &quot;{&quot; ( FieldBinding ( &quot;,&quot; FieldBinding )* )? &quot;}&quot;
FieldBinding ::= Expression &quot;:&quot; Expression
</pre></div></div>
<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>
<p>The following examples illustrate how to construct a new array with 4 items, a new object with 2 fields, and a new multiset with 5 items, respectively. Array elements or multiset elements can be homogeneous (as in the first example), which is the common case, or they may be heterogeneous (as in the third 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 a record must be strings, and duplicate field errors will be raised if they are not distinct.</p>
<div class="section">
<div class="section">
<h5><a name="Examples"></a>Examples</h5>
<div class="source">
<div class="source">
<pre>[ 'a', 'b', 'c', 'c' ]
{
'project name': 'Hyracks',
'project members': [ 'vinayakb', 'dtabass', 'chenli', 'tsotras', 'tillw' ]
}
{{ 42, &quot;forty-two!&quot;, { &quot;rank&quot;: &quot;Captain&quot;, &quot;name&quot;: &quot;America&quot; }, 3.14159, 42 }}
</pre></div></div>
<!-- ! Licensed to the Apache Software Foundation (ASF) under one
! or more contributor license agreements. See the NOTICE file
! distributed with this work for additional information
! regarding copyright ownership. The ASF licenses this file
! to you under the Apache License, Version 2.0 (the
! "License"); you may not use this file except in compliance
! with the License. You may obtain a copy of the License at
!
! http://www.apache.org/licenses/LICENSE-2.0
!
! Unless required by applicable law or agreed to in writing,
! software distributed under the License is distributed on an
! "AS IS" BASIS, WITHOUT WARRANTIES OR CONDITIONS OF ANY
! KIND, either express or implied. See the License for the
! specific language governing permissions and limitations
! under the License.
! -->
<h1><a name="Queries" id="Queries">3. Queries</a></h1>
<p>A SQL++ query can be any legal SQL++ expression or <tt>SELECT</tt> statement. A SQL++ query always ends with a semicolon.</p>
<div class="source">
<div class="source">
<pre>Query ::= (Expression | SelectStatement) &quot;;&quot;
</pre></div></div></div></div></div></div>
<div class="section">
<h2><a name="SELECT_statements" id="SELECT_statements">SELECT statements</a></h2>
<p>The following shows the (rich) grammar for the <tt>SELECT</tt> statement in SQL++.</p>
<div class="source">
<div class="source">
<pre>SelectStatement ::= ( WithClause )?
SelectSetOperation (OrderbyClause )? ( LimitClause )?
SelectSetOperation ::= SelectBlock (&lt;UNION&gt; &lt;ALL&gt; ( SelectBlock | Subquery ) )*
Subquery ::= &quot;(&quot; SelectStatement &quot;)&quot;
SelectBlock ::= SelectClause
( FromClause ( LetClause )?)?
( WhereClause )?
( GroupbyClause ( LetClause )? ( HavingClause )? )?
|
FromClause ( LetClause )?
( WhereClause )?
( GroupbyClause ( LetClause )? ( HavingClause )? )?
SelectClause
SelectClause ::= &lt;SELECT&gt; ( &lt;ALL&gt; | &lt;DISTINCT&gt; )? ( SelectRegular | SelectValue )
SelectRegular ::= Projection ( &quot;,&quot; Projection )*
SelectValue ::= ( &lt;VALUE&gt; | &lt;ELEMENT&gt; | &lt;RAW&gt; ) Expression
Projection ::= ( Expression ( &lt;AS&gt; )? Identifier | &quot;*&quot; )
FromClause ::= &lt;FROM&gt; FromTerm ( &quot;,&quot; FromTerm )*
FromTerm ::= Expression (( &lt;AS&gt; )? Variable)?
( ( JoinType )? ( JoinClause | UnnestClause ) )*
JoinClause ::= &lt;JOIN&gt; Expression (( &lt;AS&gt; )? Variable)? &lt;ON&gt; Expression
UnnestClause ::= ( &lt;UNNEST&gt; | &lt;CORRELATE&gt; | &lt;FLATTEN&gt; ) Expression
( &lt;AS&gt; )? Variable ( &lt;AT&gt; Variable )?
JoinType ::= ( &lt;INNER&gt; | &lt;LEFT&gt; ( &lt;OUTER&gt; )? )
WithClause ::= &lt;WITH&gt; WithElement ( &quot;,&quot; WithElement )*
LetClause ::= (&lt;LET&gt; | &lt;LETTING&gt;) LetElement ( &quot;,&quot; LetElement )*
LetElement ::= Variable &quot;=&quot; Expression
WithElement ::= Variable &lt;AS&gt; Expression
WhereClause ::= &lt;WHERE&gt; Expression
GroupbyClause ::= &lt;GROUP&gt; &lt;BY&gt; ( Expression ( (&lt;AS&gt;)? Variable )? ( &quot;,&quot; Expression ( (&lt;AS&gt;)? Variable )? )*
( &lt;GROUP&gt; &lt;AS&gt; Variable
(&quot;(&quot; Variable &lt;AS&gt; VariableReference (&quot;,&quot; Variable &lt;AS&gt; VariableReference )* &quot;)&quot;)?
)?
HavingClause ::= &lt;HAVING&gt; Expression
OrderbyClause ::= &lt;ORDER&gt; &lt;BY&gt; Expression ( &lt;ASC&gt; | &lt;DESC&gt; )? ( &quot;,&quot; Expression ( &lt;ASC&gt; | &lt;DESC&gt; )? )*
LimitClause ::= &lt;LIMIT&gt; Expression ( &lt;OFFSET&gt; Expression )?
</pre></div></div>
<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>
<p><tt>GleambookUsers</tt> collection (or, dataset):</p>
<div class="source">
<div class="source">
<pre>{&quot;id&quot;:1,&quot;alias&quot;:&quot;Margarita&quot;,&quot;name&quot;:&quot;MargaritaStoddard&quot;,&quot;nickname&quot;:&quot;Mags&quot;,&quot;userSince&quot;:&quot;2012-08-20T10:10:00&quot;,&quot;friendIds&quot;:[2,3,6,10],&quot;employment&quot;:[{&quot;organizationName&quot;:&quot;Codetechno&quot;,&quot;start-date&quot;:&quot;2006-08-06&quot;},{&quot;organizationName&quot;:&quot;geomedia&quot;,&quot;start-date&quot;:&quot;2010-06-17&quot;,&quot;end-date&quot;:&quot;2010-01-26&quot;}],&quot;gender&quot;:&quot;F&quot;}
{&quot;id&quot;:2,&quot;alias&quot;:&quot;Isbel&quot;,&quot;name&quot;:&quot;IsbelDull&quot;,&quot;nickname&quot;:&quot;Izzy&quot;,&quot;userSince&quot;:&quot;2011-01-22T10:10:00&quot;,&quot;friendIds&quot;:[1,4],&quot;employment&quot;:[{&quot;organizationName&quot;:&quot;Hexviafind&quot;,&quot;startDate&quot;:&quot;2010-04-27&quot;}]}
{&quot;id&quot;:3,&quot;alias&quot;:&quot;Emory&quot;,&quot;name&quot;:&quot;EmoryUnk&quot;,&quot;userSince&quot;:&quot;2012-07-10T10:10:00&quot;,&quot;friendIds&quot;:[1,5,8,9],&quot;employment&quot;:[{&quot;organizationName&quot;:&quot;geomedia&quot;,&quot;startDate&quot;:&quot;2010-06-17&quot;,&quot;endDate&quot;:&quot;2010-01-26&quot;}]}
</pre></div></div>
<p><tt>GleambookMessages</tt> collection (or, dataset):</p>
<div class="source">
<div class="source">
<pre>{&quot;messageId&quot;:2,&quot;authorId&quot;:1,&quot;inResponseTo&quot;:4,&quot;senderLocation&quot;:[41.66,80.87],&quot;message&quot;:&quot; dislike iphone its touch-screen is horrible&quot;}
{&quot;messageId&quot;:3,&quot;authorId&quot;:2,&quot;inResponseTo&quot;:4,&quot;senderLocation&quot;:[48.09,81.01],&quot;message&quot;:&quot; like samsung the plan is amazing&quot;}
{&quot;messageId&quot;:4,&quot;authorId&quot;:1,&quot;inResponseTo&quot;:2,&quot;senderLocation&quot;:[37.73,97.04],&quot;message&quot;:&quot; can't stand at&amp;t the network is horrible:(&quot;}
{&quot;messageId&quot;:6,&quot;authorId&quot;:2,&quot;inResponseTo&quot;:1,&quot;senderLocation&quot;:[31.5,75.56],&quot;message&quot;:&quot; like t-mobile its platform is mind-blowing&quot;}
{&quot;messageId&quot;:8,&quot;authorId&quot;:1,&quot;inResponseTo&quot;:11,&quot;senderLocation&quot;:[40.33,80.87],&quot;message&quot;:&quot; like verizon the 3G is awesome:)&quot;}
{&quot;messageId&quot;:10,&quot;authorId&quot;:1,&quot;inResponseTo&quot;:12,&quot;senderLocation&quot;:[42.5,70.01],&quot;message&quot;:&quot; can't stand motorola the touch-screen is terrible&quot;}
{&quot;messageId&quot;:11,&quot;authorId&quot;:1,&quot;inResponseTo&quot;:1,&quot;senderLocation&quot;:[38.97,77.49],&quot;message&quot;:&quot; can't stand at&amp;t its plan is terrible&quot;}
</pre></div></div></div>
<div class="section">
<h2><a name="SELECT_Clause"></a><a name="Select_clauses" id="Select_clauses">SELECT Clause</a></h2>
<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>
<div class="section">
<h3><a name="SELECT_VALUE_Clause"></a><a name="Select_element" id="Select_element">SELECT VALUE Clause</a></h3>
<p>The <tt>SELECT VALUE</tt> clause in SQL++ returns a collection 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>
<p>The following example shows a standard-alone <tt>SELECT VALUE</tt>, which wraps a value into an array.</p>
<div class="section">
<div class="section">
<h5><a name="Example"></a>Example</h5>
<div class="source">
<div class="source">
<pre>SELECT VALUE 1;
</pre></div></div>
<p>This query return:</p>
<div class="source">
<div class="source">
<pre>[
1
]
</pre></div></div>
<p>The following example shows a query that selects one user from the GleambookUsers collection.</p></div>
<div class="section">
<h5><a name="Example"></a>Example</h5>
<div class="source">
<div class="source">
<pre>SELECT VALUE user
FROM GleambookUsers user
WHERE user.id = 1;
</pre></div></div>
<p>This query returns:</p>
<div class="source">
<div class="source">
<pre>[{
&quot;userSince&quot;: &quot;2012-08-20T10:10:00.000Z&quot;,
&quot;friendIds&quot;: [
2,
3,
6,
10
],
&quot;gender&quot;: &quot;F&quot;,
&quot;name&quot;: &quot;MargaritaStoddard&quot;,
&quot;nickname&quot;: &quot;Mags&quot;,
&quot;alias&quot;: &quot;Margarita&quot;,
&quot;id&quot;: 1,
&quot;employment&quot;: [
{
&quot;organizationName&quot;: &quot;Codetechno&quot;,
&quot;start-date&quot;: &quot;2006-08-06&quot;
},
{
&quot;end-date&quot;: &quot;2010-01-26&quot;,
&quot;organizationName&quot;: &quot;geomedia&quot;,
&quot;start-date&quot;: &quot;2010-06-17&quot;
}
]
} ]
</pre></div></div></div></div></div>
<div class="section">
<h3><a name="SQL-style_SELECT"></a><a name="SQL_select" id="SQL_select">SQL-style SELECT</a></h3>
<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>
<div class="section">
<div class="section">
<h5><a name="Example"></a>Example</h5>
<div class="source">
<div class="source">
<pre>SELECT user.alias user_alias, user.name user_name
FROM GleambookUsers user
WHERE user.id = 1;
</pre></div></div>
<p>Returns:</p>
<div class="source">
<div class="source">
<pre>[ {
&quot;user_name&quot;: &quot;MargaritaStoddard&quot;,
&quot;user_alias&quot;: &quot;Margarita&quot;
} ]
</pre></div></div></div></div></div>
<div class="section">
<h3><a name="SELECT_"></a><a name="Select_star" id="Select_star">SELECT *</a></h3>
<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>
<div class="section">
<div class="section">
<h5><a name="Example"></a>Example</h5>
<div class="source">
<div class="source">
<pre>SELECT *
FROM GleambookUsers user;
</pre></div></div>
<p>Since <tt>user</tt> is the only binding variable generated in the <tt>FROM</tt> clause, this query returns:</p>
<div class="source">
<div class="source">
<pre>[ {
&quot;user&quot;: {
&quot;userSince&quot;: &quot;2012-08-20T10:10:00.000Z&quot;,
&quot;friendIds&quot;: [
2,
3,
6,
10
],
&quot;gender&quot;: &quot;F&quot;,
&quot;name&quot;: &quot;MargaritaStoddard&quot;,
&quot;nickname&quot;: &quot;Mags&quot;,
&quot;alias&quot;: &quot;Margarita&quot;,
&quot;id&quot;: 1,
&quot;employment&quot;: [
{
&quot;organizationName&quot;: &quot;Codetechno&quot;,
&quot;start-date&quot;: &quot;2006-08-06&quot;
},
{
&quot;end-date&quot;: &quot;2010-01-26&quot;,
&quot;organizationName&quot;: &quot;geomedia&quot;,
&quot;start-date&quot;: &quot;2010-06-17&quot;
}
]
}
}, {
&quot;user&quot;: {
&quot;userSince&quot;: &quot;2011-01-22T10:10:00.000Z&quot;,
&quot;friendIds&quot;: [
1,
4
],
&quot;name&quot;: &quot;IsbelDull&quot;,
&quot;nickname&quot;: &quot;Izzy&quot;,
&quot;alias&quot;: &quot;Isbel&quot;,
&quot;id&quot;: 2,
&quot;employment&quot;: [
{
&quot;organizationName&quot;: &quot;Hexviafind&quot;,
&quot;startDate&quot;: &quot;2010-04-27&quot;
}
]
}
}, {
&quot;user&quot;: {
&quot;userSince&quot;: &quot;2012-07-10T10:10:00.000Z&quot;,
&quot;friendIds&quot;: [
1,
5,
8,
9
],
&quot;name&quot;: &quot;EmoryUnk&quot;,
&quot;alias&quot;: &quot;Emory&quot;,
&quot;id&quot;: 3,
&quot;employment&quot;: [
{
&quot;organizationName&quot;: &quot;geomedia&quot;,
&quot;endDate&quot;: &quot;2010-01-26&quot;,
&quot;startDate&quot;: &quot;2010-06-17&quot;
}
]
}
} ]
</pre></div></div></div>
<div class="section">
<h5><a name="Example"></a>Example</h5>
<div class="source">
<div class="source">
<pre>SELECT *
FROM GleambookUsers u, GleambookMessages m
WHERE m.authorId = u.id and u.id = 2;
</pre></div></div>
<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 variable generated in the <tt>FROM</tt> clause, this query returns:</p>
<div class="source">
<div class="source">
<pre>[ {
&quot;u&quot;: {
&quot;userSince&quot;: &quot;2011-01-22T10:10:00&quot;,
&quot;friendIds&quot;: [
1,
4
],
&quot;name&quot;: &quot;IsbelDull&quot;,
&quot;nickname&quot;: &quot;Izzy&quot;,
&quot;alias&quot;: &quot;Isbel&quot;,
&quot;id&quot;: 2,
&quot;employment&quot;: [
{
&quot;organizationName&quot;: &quot;Hexviafind&quot;,
&quot;startDate&quot;: &quot;2010-04-27&quot;
}
]
},
&quot;m&quot;: {
&quot;senderLocation&quot;: [
31.5,
75.56
],
&quot;inResponseTo&quot;: 1,
&quot;messageId&quot;: 6,
&quot;authorId&quot;: 2,
&quot;message&quot;: &quot; like t-mobile its platform is mind-blowing&quot;
}
}, {
&quot;u&quot;: {
&quot;userSince&quot;: &quot;2011-01-22T10:10:00&quot;,
&quot;friendIds&quot;: [
1,
4
],
&quot;name&quot;: &quot;IsbelDull&quot;,
&quot;nickname&quot;: &quot;Izzy&quot;,
&quot;alias&quot;: &quot;Isbel&quot;,
&quot;id&quot;: 2,
&quot;employment&quot;: [
{
&quot;organizationName&quot;: &quot;Hexviafind&quot;,
&quot;startDate&quot;: &quot;2010-04-27&quot;
}
]
},
&quot;m&quot;: {
&quot;senderLocation&quot;: [
48.09,
81.01
],
&quot;inResponseTo&quot;: 4,
&quot;messageId&quot;: 3,
&quot;authorId&quot;: 2,
&quot;message&quot;: &quot; like samsung the plan is amazing&quot;
}
} ]
</pre></div></div></div></div></div>
<div class="section">
<h3><a name="SELECT_DISTINCT"></a><a name="Select_distinct" id="Select_distinct">SELECT DISTINCT</a></h3>
<p>SQL++&#x2019;s <tt>DISTINCT</tt> keyword is used to eliminate duplicate items in results. The following example shows how it works.</p>
<div class="section">
<div class="section">
<h5><a name="Example"></a>Example</h5>
<div class="source">
<div class="source">
<pre>SELECT DISTINCT * FROM [1, 2, 2, 3] AS foo;
</pre></div></div>
<p>This query returns:</p>
<div class="source">
<div class="source">
<pre>[ {
&quot;foo&quot;: 1
}, {
&quot;foo&quot;: 2
}, {
&quot;foo&quot;: 3
} ]
</pre></div></div></div>
<div class="section">
<h5><a name="Example"></a>Example</h5>
<div class="source">
<div class="source">
<pre>SELECT DISTINCT VALUE foo FROM [1, 2, 2, 3] AS foo;
</pre></div></div>
<p>This version of the query returns:</p>
<div class="source">
<div class="source">
<pre>[ 1
, 2
, 3
]
</pre></div></div></div></div></div>
<div class="section">
<h3><a name="Unnamed_projections" id="Unnamed_projections">Unnamed projections</a></h3>
<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>
<ul>
<li>If a projection expression is a variable reference expression, its generated name is the name of the variable.</li>
<li>If a projection expression is a field access expression, its generated name is the last identifier in the expression.</li>
<li>For all other cases, the query processor will generate a unique name.</li>
</ul>
<div class="section">
<div class="section">
<h5><a name="Example"></a>Example</h5>
<div class="source">
<div class="source">
<pre>SELECT substr(user.name, 10), user.alias
FROM GleambookUsers user
WHERE user.id = 1;
</pre></div></div>
<p>This query outputs:</p>
<div class="source">
<div class="source">
<pre>[ {
&quot;alias&quot;: &quot;Margarita&quot;,
&quot;$1&quot;: &quot;Stoddard&quot;
} ]
</pre></div></div>
<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>
<div class="section">
<h3><a name="Abbreviated_Field_Access_Expressions"></a><a name="Abbreviatory_field_access_expressions" id="Abbreviatory_field_access_expressions">Abbreviated Field Access Expressions</a></h3>
<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>
<div class="section">
<div class="section">
<h5><a name="Example"></a>Example</h5>
<div class="source">
<div class="source">
<pre>SELECT substr(name, 10) AS lname, alias
FROM GleambookUsers user
WHERE id = 1;
</pre></div></div>
<p>Outputs:</p>
<div class="source">
<div class="source">
<pre>[ {
&quot;lname&quot;: &quot;Stoddard&quot;,
&quot;alias&quot;: &quot;Margarita&quot;
} ]
</pre></div></div></div></div></div></div>
<div class="section">
<h2><a name="UNNEST_Clause"></a><a name="Unnest_clauses" id="Unnest_clauses">UNNEST Clause</a></h2>
<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>
<div class="section">
<h3><a name="Inner_UNNEST"></a><a name="Inner_unnests" id="Inner_unnests">Inner UNNEST</a></h3>
<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>
<div class="section">
<div class="section">
<h5><a name="Example"></a>Example</h5>
<div class="source">
<div class="source">
<pre>SELECT u.id AS userId, e.organizationName AS orgName
FROM GleambookUsers u
UNNEST u.employment e
WHERE u.id = 1;
</pre></div></div>
<p>This query returns:</p>
<div class="source">
<div class="source">
<pre>[ {
&quot;orgName&quot;: &quot;Codetechno&quot;,
&quot;userId&quot;: 1
}, {
&quot;orgName&quot;: &quot;geomedia&quot;,
&quot;userId&quot;: 1
} ]
</pre></div></div>
<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>
<div class="section">
<h3><a name="Left_outer_UNNEST"></a><a name="Left_outer_unnests" id="Left_outer_unnests">Left outer UNNEST</a></h3>
<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>
<div class="section">
<div class="section">
<h5><a name="Example"></a>Example</h5>
<div class="source">
<div class="source">
<pre>SELECT u.id AS userId, h.hobbyName AS hobby
FROM GleambookUsers u
LEFT OUTER UNNEST u.hobbies h
WHERE u.id = 1;
</pre></div></div>
<p>Returns:</p>
<div class="source">
<div class="source">
<pre>[ {
&quot;userId&quot;: 1
} ]
</pre></div></div>
<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>
<div class="section">
<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>
<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>
<div class="section">
<div class="section">
<h5><a name="Example"></a>Example</h5>
<div class="source">
<div class="source">
<pre>SELECT u.name AS uname, m.message AS message
FROM GleambookUsers u
UNNEST GleambookMessages m
WHERE m.authorId = u.id;
</pre></div></div>
<p>This returns:</p>
<div class="source">
<div class="source">
<pre>[ {
&quot;uname&quot;: &quot;MargaritaStoddard&quot;,
&quot;message&quot;: &quot; can't stand at&amp;t its plan is terrible&quot;
}, {
&quot;uname&quot;: &quot;MargaritaStoddard&quot;,
&quot;message&quot;: &quot; dislike iphone its touch-screen is horrible&quot;
}, {
&quot;uname&quot;: &quot;MargaritaStoddard&quot;,
&quot;message&quot;: &quot; can't stand at&amp;t the network is horrible:(&quot;
}, {
&quot;uname&quot;: &quot;MargaritaStoddard&quot;,
&quot;message&quot;: &quot; like verizon the 3G is awesome:)&quot;
}, {
&quot;uname&quot;: &quot;MargaritaStoddard&quot;,
&quot;message&quot;: &quot; can't stand motorola the touch-screen is terrible&quot;
}, {
&quot;uname&quot;: &quot;IsbelDull&quot;,
&quot;message&quot;: &quot; like t-mobile its platform is mind-blowing&quot;
}, {
&quot;uname&quot;: &quot;IsbelDull&quot;,
&quot;message&quot;: &quot; like samsung the plan is amazing&quot;
} ]
</pre></div></div>
<p>Similarly, the above query can also be expressed as the <tt>UNNEST</tt>ing of a correlated SQL++ subquery:</p></div>
<div class="section">
<h5><a name="Example"></a>Example</h5>
<div class="source">
<div class="source">
<pre>SELECT u.name AS uname, m.message AS message
FROM GleambookUsers u
UNNEST (
SELECT VALUE msg
FROM GleambookMessages msg
WHERE msg.authorId = u.id
) AS m;
</pre></div></div></div></div></div></div>
<div class="section">
<h2><a name="FROM_clauses"></a><a name="From_clauses" id="From_clauses">FROM clauses</a></h2>
<p>A <tt>FROM</tt> clause is used for enumerating (i.e., conceptually iterating over) the contents of collections, as in SQL.</p>
<div class="section">
<h3><a name="Binding_expressions" id="Binding_expressions">Binding expressions</a></h3>
<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>
<div class="section">
<div class="section">
<h5><a name="Example"></a>Example</h5>
<div class="source">
<div class="source">
<pre>SELECT VALUE foo
FROM [1, 2, 2, 3] AS foo
WHERE foo &gt; 2;
</pre></div></div>
<p>Returns:</p>
<div class="source">
<div class="source">
<pre>[
3
]
</pre></div></div></div></div></div>
<div class="section">
<h3><a name="Multiple_FROM_terms"></a><a name="Multiple_from_terms" id="Multiple_from_terms">Multiple FROM terms</a></h3>
<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>
<div class="section">
<div class="section">
<h5><a name="Example"></a>Example</h5>
<div class="source">
<div class="source">
<pre>SELECT u.id AS userId, e.organizationName AS orgName
FROM GleambookUsers u, u.employment e
WHERE u.id = 1;
</pre></div></div></div></div></div>
<div class="section">
<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>
<p>Similarly, the join intentions of the other <tt>UNNEST</tt>-based join examples above could be expressed as:</p>
<div class="section">
<div class="section">
<h5><a name="Example"></a>Example</h5>
<div class="source">
<div class="source">
<pre>SELECT u.name AS uname, m.message AS message
FROM GleambookUsers u, GleambookMessages m
WHERE m.authorId = u.id;
</pre></div></div></div>
<div class="section">
<h5><a name="Example"></a>Example</h5>
<div class="source">
<div class="source">
<pre>SELECT u.name AS uname, m.message AS message
FROM GleambookUsers u,
(
SELECT VALUE msg
FROM GleambookMessages msg
WHERE msg.authorId = u.id
) AS m;
</pre></div></div>
<p>Note that the first alternative is one of the SQL-92 approaches to expressing a join.</p></div></div></div>
<div class="section">
<h3><a name="Implicit_binding_variables" id="Implicit_binding_variables">Implicit binding variables</a></h3>
<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>
<ul>
<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>
<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>
<li>For all other cases, a compilation error will be raised.</li>
</ul>
<p>The next two examples show queries that do not provide binding variables in their <tt>FROM</tt> clauses.</p>
<div class="section">
<div class="section">
<h5><a name="Example"></a>Example</h5>
<div class="source">
<div class="source">
<pre>SELECT GleambookUsers.name, GleambookMessages.message
FROM GleambookUsers, GleambookMessages
WHERE GleambookMessages.authorId = GleambookUsers.id;
</pre></div></div>
<p>Returns:</p>
<div class="source">
<div class="source">
<pre>[ {
&quot;name&quot;: &quot;MargaritaStoddard&quot;,
&quot;message&quot;: &quot; like verizon the 3G is awesome:)&quot;
}, {
&quot;name&quot;: &quot;MargaritaStoddard&quot;,
&quot;message&quot;: &quot; can't stand motorola the touch-screen is terrible&quot;
}, {
&quot;name&quot;: &quot;MargaritaStoddard&quot;,
&quot;message&quot;: &quot; can't stand at&amp;t its plan is terrible&quot;
}, {
&quot;name&quot;: &quot;MargaritaStoddard&quot;,
&quot;message&quot;: &quot; dislike iphone its touch-screen is horrible&quot;
}, {
&quot;name&quot;: &quot;MargaritaStoddard&quot;,
&quot;message&quot;: &quot; can't stand at&amp;t the network is horrible:(&quot;
}, {
&quot;name&quot;: &quot;IsbelDull&quot;,
&quot;message&quot;: &quot; like samsung the plan is amazing&quot;
}, {
&quot;name&quot;: &quot;IsbelDull&quot;,
&quot;message&quot;: &quot; like t-mobile its platform is mind-blowing&quot;
} ]
</pre></div></div></div>
<div class="section">
<h5><a name="Example"></a>Example</h5>
<div class="source">
<div class="source">
<pre>SELECT GleambookUsers.name, GleambookMessages.message
FROM GleambookUsers,
(
SELECT VALUE GleambookMessages
FROM GleambookMessages
WHERE GleambookMessages.authorId = GleambookUsers.id
);
</pre></div></div>
<p>Returns:</p>
<div class="source">
<div class="source">
<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;,
&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;
</pre></div></div></div></div></div></div>
<div class="section">
<h2><a name="JOIN_clauses"></a><a name="Join_clauses" id="Join_clauses">JOIN clauses</a></h2>
<p>The join clause in SQL++ supports both inner joins and left outer joins from standard SQL.</p>
<div class="section">
<h3><a name="Inner_joins" id="Inner_joins">Inner joins</a></h3>
<p>Using a <tt>JOIN</tt> clause, the inner join intent from the preceeding examples can also be expressed as follows:</p>
<div class="section">
<div class="section">
<h5><a name="Example"></a>Example</h5>
<div class="source">
<div class="source">
<pre>SELECT u.name AS uname, m.message AS message
FROM GleambookUsers u JOIN GleambookMessages m ON m.authorId = u.id;
</pre></div></div></div></div></div>
<div class="section">
<h3><a name="Left_outer_joins" id="Left_outer_joins">Left outer joins</a></h3>
<p>SQL++ supports SQL&#x2019;s notion of left outer join. The following query is an example:</p>
<div class="source">
<div class="source">
<pre>SELECT u.name AS uname, m.message AS message
FROM GleambookUsers u LEFT OUTER JOIN GleambookMessages m ON m.authorId = u.id;
</pre></div></div>
<p>Returns:</p>
<div class="source">
<div class="source">
<pre>[ {
&quot;uname&quot;: &quot;MargaritaStoddard&quot;,
&quot;message&quot;: &quot; like verizon the 3G is awesome:)&quot;
}, {
&quot;uname&quot;: &quot;MargaritaStoddard&quot;,
&quot;message&quot;: &quot; can't stand motorola the touch-screen is terrible&quot;
}, {
&quot;uname&quot;: &quot;MargaritaStoddard&quot;,
&quot;message&quot;: &quot; can't stand at&amp;t its plan is terrible&quot;
}, {
&quot;uname&quot;: &quot;MargaritaStoddard&quot;,
&quot;message&quot;: &quot; dislike iphone its touch-screen is horrible&quot;
}, {
&quot;uname&quot;: &quot;MargaritaStoddard&quot;,
&quot;message&quot;: &quot; can't stand at&amp;t the network is horrible:(&quot;
}, {
&quot;uname&quot;: &quot;IsbelDull&quot;,
&quot;message&quot;: &quot; like samsung the plan is amazing&quot;
}, {
&quot;uname&quot;: &quot;IsbelDull&quot;,
&quot;message&quot;: &quot; like t-mobile its platform is mind-blowing&quot;
}, {
&quot;uname&quot;: &quot;EmoryUnk&quot;
} ]
</pre></div></div>
<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>
<p>The left-outer join query can also be expressed using <tt>LEFT OUTER UNNEST</tt>:</p>
<div class="source">
<div class="source">
<pre>SELECT u.name AS uname, m.message AS message
FROM GleambookUsers u
LEFT OUTER UNNEST (
SELECT VALUE message
FROM GleambookMessages message
WHERE message.authorId = u.id
) m;
</pre></div></div>
<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>
<div class="section">
<h2><a name="GROUP_BY_clauses"></a><a name="Group_By_clauses" id="Group_By_clauses">GROUP BY clauses</a></h2>
<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>
<div class="section">
<h3><a name="Group_variables" id="Group_variables">Group variables</a></h3>
<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>
<div class="source">
<div class="source">
<pre>&lt;GROUP&gt; &lt;AS&gt; Variable (&quot;(&quot; Variable &lt;AS&gt; VariableReference (&quot;,&quot; Variable &lt;AS&gt; VariableReference )* &quot;)&quot;)?
</pre></div></div>
<div class="section">
<div class="section">
<h5><a name="Example"></a>Example</h5>
<div class="source">
<div class="source">
<pre>SELECT *
FROM GleambookMessages message
GROUP BY message.authorId AS uid GROUP AS msgs(message AS msg);
</pre></div></div>
<p>This first example query returns:</p>
<div class="source">
<div class="source">
<pre>[ {
&quot;msgs&quot;: [
{
&quot;msg&quot;: {
&quot;senderLocation&quot;: [
38.97,
77.49
],
&quot;inResponseTo&quot;: 1,
&quot;messageId&quot;: 11,
&quot;authorId&quot;: 1,
&quot;message&quot;: &quot; can't stand at&amp;t its plan is terrible&quot;
}
},
{
&quot;msg&quot;: {
&quot;senderLocation&quot;: [
41.66,
80.87
],
&quot;inResponseTo&quot;: 4,
&quot;messageId&quot;: 2,
&quot;authorId&quot;: 1,
&quot;message&quot;: &quot; dislike iphone its touch-screen is horrible&quot;
}
},
{
&quot;msg&quot;: {
&quot;senderLocation&quot;: [
37.73,
97.04
],
&quot;inResponseTo&quot;: 2,
&quot;messageId&quot;: 4,
&quot;authorId&quot;: 1,
&quot;message&quot;: &quot; can't stand at&amp;t the network is horrible:(&quot;
}
},
{
&quot;msg&quot;: {
&quot;senderLocation&quot;: [
40.33,
80.87
],
&quot;inResponseTo&quot;: 11,
&quot;messageId&quot;: 8,
&quot;authorId&quot;: 1,
&quot;message&quot;: &quot; like verizon the 3G is awesome:)&quot;
}
},
{
&quot;msg&quot;: {
&quot;senderLocation&quot;: [
42.5,
70.01
],
&quot;inResponseTo&quot;: 12,
&quot;messageId&quot;: 10,
&quot;authorId&quot;: 1,
&quot;message&quot;: &quot; can't stand motorola the touch-screen is terrible&quot;
}
}
],
&quot;uid&quot;: 1
}, {
&quot;msgs&quot;: [
{
&quot;msg&quot;: {
&quot;senderLocation&quot;: [
31.5,
75.56
],
&quot;inResponseTo&quot;: 1,
&quot;messageId&quot;: 6,
&quot;authorId&quot;: 2,
&quot;message&quot;: &quot; like t-mobile its platform is mind-blowing&quot;
}
},
{
&quot;msg&quot;: {
&quot;senderLocation&quot;: [
48.09,
81.01
],
&quot;inResponseTo&quot;: 4,
&quot;messageId&quot;: 3,
&quot;authorId&quot;: 2,
&quot;message&quot;: &quot; like samsung the plan is amazing&quot;
}
}
],
&quot;uid&quot;: 2
} ]
</pre></div></div>
<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>
<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>
<div class="section">
<h5><a name="Example"></a>Example</h5>
<div class="source">
<div class="source">
<pre>SELECT uid, (SELECT VALUE g.msg FROM g) AS msgs
FROM GleambookMessages gbm
GROUP BY gbm.authorId AS uid
GROUP AS g(gbm as msg);
</pre></div></div>
<p>This variant of the example query returns:</p>
<div class="source">
<div class="source">
<pre> [ {
&quot;msgs&quot;: [
{
&quot;senderLocation&quot;: [
38.97,
77.49
],
&quot;inResponseTo&quot;: 1,
&quot;messageId&quot;: 11,
&quot;authorId&quot;: 1,
&quot;message&quot;: &quot; can't stand at&amp;t its plan is terrible&quot;
},
{
&quot;senderLocation&quot;: [
41.66,
80.87
],
&quot;inResponseTo&quot;: 4,
&quot;messageId&quot;: 2,
&quot;authorId&quot;: 1,
&quot;message&quot;: &quot; dislike iphone its touch-screen is horrible&quot;
},
{
&quot;senderLocation&quot;: [
37.73,
97.04
],
&quot;inResponseTo&quot;: 2,
&quot;messageId&quot;: 4,
&quot;authorId&quot;: 1,
&quot;message&quot;: &quot; can't stand at&amp;t the network is horrible:(&quot;
},
{
&quot;senderLocation&quot;: [
40.33,
80.87
],
&quot;inResponseTo&quot;: 11,
&quot;messageId&quot;: 8,
&quot;authorId&quot;: 1,
&quot;message&quot;: &quot; like verizon the 3G is awesome:)&quot;
},
{
&quot;senderLocation&quot;: [
42.5,
70.01
],
&quot;inResponseTo&quot;: 12,
&quot;messageId&quot;: 10,
&quot;authorId&quot;: 1,
&quot;message&quot;: &quot; can't stand motorola the touch-screen is terrible&quot;
}
],
&quot;uid&quot;: 1
}, {
&quot;msgs&quot;: [
{
&quot;senderLocation&quot;: [
31.5,
75.56
],
&quot;inResponseTo&quot;: 1,
&quot;messageId&quot;: 6,
&quot;authorId&quot;: 2,
&quot;message&quot;: &quot; like t-mobile its platform is mind-blowing&quot;
},
{
&quot;senderLocation&quot;: [
48.09,
81.01
],
&quot;inResponseTo&quot;: 4,
&quot;messageId&quot;: 3,
&quot;authorId&quot;: 2,
&quot;message&quot;: &quot; like samsung the plan is amazing&quot;
}
],
&quot;uid&quot;: 2
} ]
</pre></div></div>
<p>Because this is a fairly common case, a third variant with output identical to the second variant is also possible:</p></div>
<div class="section">
<h5><a name="Example"></a>Example</h5>
<div class="source">
<div class="source">
<pre>SELECT uid, msg AS msgs
FROM GleambookMessages gbm
GROUP BY gbm.authorId AS uid
GROUP AS g(gbm as msg);
</pre></div></div>
<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>
<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>
<div class="section">
<h5><a name="Example"></a>Example</h5>
<div class="source">
<div class="source">
<pre>SELECT uid,
(SELECT VALUE g.msg
FROM g
WHERE g.msg.message LIKE '% like%'
ORDER BY g.msg.messageId
LIMIT 2) AS msgs
FROM GleambookMessages gbm
GROUP BY gbm.authorId AS uid
GROUP AS g(gbm as msg);
</pre></div></div>
<p>This example query returns:</p>
<div class="source">
<div class="source">
<pre>[ {
&quot;msgs&quot;: [
{
&quot;senderLocation&quot;: [
40.33,
80.87
],
&quot;inResponseTo&quot;: 11,
&quot;messageId&quot;: 8,
&quot;authorId&quot;: 1,
&quot;message&quot;: &quot; like verizon the 3G is awesome:)&quot;
}
],
&quot;uid&quot;: 1
}, {
&quot;msgs&quot;: [
{
&quot;senderLocation&quot;: [
48.09,
81.01
],
&quot;inResponseTo&quot;: 4,
&quot;messageId&quot;: 3,
&quot;authorId&quot;: 2,
&quot;message&quot;: &quot; like samsung the plan is amazing&quot;
},
{
&quot;senderLocation&quot;: [
31.5,
75.56
],
&quot;inResponseTo&quot;: 1,
&quot;messageId&quot;: 6,
&quot;authorId&quot;: 2,
&quot;message&quot;: &quot; like t-mobile its platform is mind-blowing&quot;
}
],
&quot;uid&quot;: 2
} ]
</pre></div></div></div></div></div>
<div class="section">
<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>
<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>
<ul>
<li>If the grouping key expression is a variable reference expression, the generated variable gets the same name as the referred variable;</li>
<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>
<li>For all other cases, the compiler generates a unique variable (but the user query is unable to refer to this generated variable).</li>
</ul>
<p>The next example illustrates a query that doesn&#x2019;t provide binding variables for its grouping key expressions.</p>
<div class="section">
<div class="section">
<h5><a name="Example"></a>Example</h5>
<div class="source">
<div class="source">
<pre>SELECT authorId,
(SELECT VALUE g.msg
FROM g
WHERE g.msg.message LIKE '% like%'
ORDER BY g.msg.messageId
LIMIT 2) AS msgs
FROM GleambookMessages gbm
GROUP BY gbm.authorId
GROUP AS g(gbm as msg);
</pre></div></div>
<p>This query returns:</p>
<div class="source">
<div class="source">
<pre> [ {
&quot;msgs&quot;: [
{
&quot;senderLocation&quot;: [
40.33,
80.87
],
&quot;inResponseTo&quot;: 11,
&quot;messageId&quot;: 8,
&quot;authorId&quot;: 1,
&quot;message&quot;: &quot; like verizon the 3G is awesome:)&quot;
}
],
&quot;authorId&quot;: 1
}, {
&quot;msgs&quot;: [
{
&quot;senderLocation&quot;: [
48.09,
81.01
],
&quot;inResponseTo&quot;: 4,
&quot;messageId&quot;: 3,
&quot;authorId&quot;: 2,
&quot;message&quot;: &quot; like samsung the plan is amazing&quot;
},
{
&quot;senderLocation&quot;: [
31.5,
75.56
],
&quot;inResponseTo&quot;: 1,
&quot;messageId&quot;: 6,
&quot;authorId&quot;: 2,
&quot;message&quot;: &quot; like t-mobile its platform is mind-blowing&quot;
}
],
&quot;authorId&quot;: 2
} ]
</pre></div></div>
<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>
<div class="section">
<h3><a name="Implicit_group_variables" id="Implicit_group_variables">Implicit group variables</a></h3>
<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>
<div class="section">
<div class="section">
<h5><a name="Example"></a>Example</h5>
<div class="source">
<div class="source">
<pre>SELECT uid,
(SELECT m.message
FROM message m
WHERE m.message LIKE '% like%'
ORDER BY m.messageId
LIMIT 2) AS msgs
FROM GleambookMessages message
GROUP BY message.authorId AS uid;
</pre></div></div>
<p>This query returns:</p>
<div class="source">
<div class="source">
<pre>[ {
&quot;msgs&quot;: [
{
&quot;message&quot;: &quot; like verizon the 3G is awesome:)&quot;
}
],
&quot;uid&quot;: 1
}, {
&quot;msgs&quot;: [
{
&quot;message&quot;: &quot; like samsung the plan is amazing&quot;
},
{
&quot;message&quot;: &quot; like t-mobile its platform is mind-blowing&quot;
}
],
&quot;uid&quot;: 2
} ]
</pre></div></div>
<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>
<div class="source">
<div class="source">
<pre>SELECT uid,
(SELECT g.msg.message
FROM g
WHERE g.msg.message LIKE '% like%'
ORDER BY g.msg.messageId
LIMIT 2) AS msgs
FROM GleambookMessages gbm
GROUP BY gbm.authorId AS uid GROUP AS g(gbm as msg);
</pre></div></div></div></div></div>
<div class="section">
<h3><a name="Aggregation_functions" id="Aggregation_functions">Aggregation functions</a></h3>
<p>In traditional SQL, which doesn&#x2019;t support nested data, grouping always also involves the use of aggregation to compute properties of the groups (e.g., the average number of messages per user rather than the actual set of messages per user). Each aggregation function in SQL++ takes a collection (e.g., 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>
<table border="0" class="table table-striped">
<thead>
<tr class="a">
<th>Function </th>
<th>NULL </th>
<th>MISSING </th>
<th>Empty Collection </th>
</tr>
</thead>
<tbody>
<tr class="b">
<td>COLL_COUNT </td>
<td>counted </td>
<td>counted </td>
<td>0 </td>
</tr>
<tr class="a">
<td>COLL_SUM </td>
<td>returns NULL </td>
<td>returns NULL </td>
<td>returns NULL </td>
</tr>
<tr class="b">
<td>COLL_MAX </td>
<td>returns NULL </td>
<td>returns NULL </td>
<td>returns NULL </td>
</tr>
<tr class="a">
<td>COLL_MIN </td>
<td>returns NULL </td>
<td>returns NULL </td>
<td>returns NULL </td>
</tr>
<tr class="b">
<td>COLL_AVG </td>
<td>returns NULL </td>
<td>returns NULL </td>
<td>returns NULL </td>
</tr>
<tr class="a">
<td>ARRAY_COUNT </td>
<td>not counted </td>
<td>not counted </td>
<td>0 </td>
</tr>
<tr class="b">
<td>ARRAY_SUM </td>
<td>ignores NULL </td>
<td>ignores NULL </td>
<td>returns NULL </td>
</tr>
<tr class="a">
<td>ARRAY_MAX </td>
<td>ignores NULL </td>
<td>ignores NULL </td>
<td>returns NULL </td>
</tr>
<tr class="b">
<td>ARRAY_MIN </td>
<td>ignores NULL </td>
<td>ignores NULL </td>
<td>returns NULL </td>
</tr>
<tr class="a">
<td>ARRAY_AVG </td>
<td>ignores NULL </td>
<td>ignores NULL </td>
<td>returns NULL </td>
</tr>
</tbody>
</table>
<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>
<div class="section">
<div class="section">
<h5><a name="Example"></a>Example</h5>
<div class="source">
<div class="source">
<pre>ARRAY_AVG(
(
SELECT VALUE ARRAY_COUNT(friendIds) FROM GleambookUsers
)
);
</pre></div></div>
<p>This example returns:</p>
<div class="source">
<div class="source">
<pre>3.3333333333333335
</pre></div></div></div>
<div class="section">
<h5><a name="Example"></a>Example</h5>
<div class="source">
<div class="source">
<pre>SELECT uid AS uid, ARRAY_COUNT(grp) AS msgCnt
FROM GleambookMessages message
GROUP BY message.authorId AS uid GROUP AS grp(message AS msg);
</pre></div></div>
<p>This query returns:</p>
<div class="source">
<div class="source">
<pre>[ {
&quot;uid&quot;: 1,
&quot;msgCnt&quot;: 5
}, {
&quot;uid&quot;: 2,
&quot;msgCnt&quot;: 2
} ]
</pre></div></div>
<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>
<div class="section">
<h3><a name="SQL-92_aggregation_functions" id="SQL-92_aggregation_functions">SQL-92 aggregation functions</a></h3>
<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>
<div class="section">
<div class="section">
<h5><a name="Example"></a>Example</h5>
<div class="source">
<div class="source">
<pre>SELECT uid, COUNT(*) AS msgCnt
FROM GleambookMessages msg
GROUP BY msg.authorId AS uid;
</pre></div></div>
<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>
<div class="source">
<div class="source">
<pre>SELECT uid AS uid, ARRAY_COUNT( (SELECT VALUE 1 FROM `$1` as g) ) AS msgCnt
FROM GleambookMessages msg
GROUP BY msg.authorId AS uid GROUP AS `$1`(msg AS msg);
</pre></div></div>
<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>
<div class="section">
<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>
<p>SQL++ provides full support for SQL-92 <tt>GROUP BY</tt> aggregation queries. The following query is such an example:</p>
<div class="section">
<div class="section">
<h5><a name="Example"></a>Example</h5>
<div class="source">
<div class="source">
<pre>SELECT msg.authorId, COUNT(msg)
FROM GleambookMessages msg
GROUP BY msg.authorId;
</pre></div></div>
<p>This query outputs:</p>
<div class="source">
<div class="source">
<pre>[ {
&quot;authorId&quot;: 1,
&quot;$1&quot;: 5
}, {
&quot;authorId&quot;: 2,
&quot;$1&quot;: 2
} ]
</pre></div></div>
<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>
<div class="source">
<div class="source">
<pre>SELECT authorId AS authorId, ARRAY_COUNT( (SELECT g.msg FROM `$1` AS g) )
FROM GleambookMessages msg
GROUP BY msg.authorId AS authorId GROUP AS `$1`(msg AS msg);
</pre></div></div></div></div></div>
<div class="section">
<h3><a name="Column_aliases" id="Column_aliases">Column aliases</a></h3>
<p>SQL++ also allows column aliases to be used as <tt>GROUP BY</tt> keys or <tt>ORDER BY</tt> keys.</p>
<div class="section">
<div class="section">
<h5><a name="Example"></a>Example</h5>
<div class="source">
<div class="source">
<pre>SELECT msg.authorId AS aid, COUNT(msg)
FROM GleambookMessages msg
GROUP BY aid;
</pre></div></div>
<p>This query returns:</p>
<div class="source">
<div class="source">
<pre>[ {
&quot;$1&quot;: 5,
&quot;aid&quot;: 1
}, {
&quot;$1&quot;: 2,
&quot;aid&quot;: 2
} ]
</pre></div></div></div></div></div></div>
<div class="section">
<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>
<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>
<div class="section">
<h2><a name="ORDER_BY_clauses"></a><a name="Order_By_clauses" id="Order_By_clauses">ORDER BY clauses</a></h2>
<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>
<div class="section">
<div class="section">
<div class="section">
<h5><a name="Example"></a>Example</h5>
<div class="source">
<div class="source">
<pre> SELECT VALUE user
FROM GleambookUsers AS user
ORDER BY ARRAY_COUNT(user.friendIds) DESC;
</pre></div></div>
<p>This query returns:</p>
<div class="source">
<div class="source">
<pre> [ {
&quot;userSince&quot;: &quot;2012-08-20T10:10:00.000Z&quot;,
&quot;friendIds&quot;: [
2,
3,
6,
10
],
&quot;gender&quot;: &quot;F&quot;,
&quot;name&quot;: &quot;MargaritaStoddard&quot;,
&quot;nickname&quot;: &quot;Mags&quot;,
&quot;alias&quot;: &quot;Margarita&quot;,
&quot;id&quot;: 1,
&quot;employment&quot;: [
{
&quot;organizationName&quot;: &quot;Codetechno&quot;,
&quot;start-date&quot;: &quot;2006-08-06&quot;
},
{
&quot;end-date&quot;: &quot;2010-01-26&quot;,
&quot;organizationName&quot;: &quot;geomedia&quot;,
&quot;start-date&quot;: &quot;2010-06-17&quot;
}
]
}, {
&quot;userSince&quot;: &quot;2012-07-10T10:10:00.000Z&quot;,
&quot;friendIds&quot;: [
1,
5,
8,
9
],
&quot;name&quot;: &quot;EmoryUnk&quot;,
&quot;alias&quot;: &quot;Emory&quot;,
&quot;id&quot;: 3,
&quot;employment&quot;: [
{
&quot;organizationName&quot;: &quot;geomedia&quot;,
&quot;endDate&quot;: &quot;2010-01-26&quot;,
&quot;startDate&quot;: &quot;2010-06-17&quot;
}
]
}, {
&quot;userSince&quot;: &quot;2011-01-22T10:10:00.000Z&quot;,
&quot;friendIds&quot;: [
1,
4
],
&quot;name&quot;: &quot;IsbelDull&quot;,
&quot;nickname&quot;: &quot;Izzy&quot;,
&quot;alias&quot;: &quot;Isbel&quot;,
&quot;id&quot;: 2,
&quot;employment&quot;: [
{
&quot;organizationName&quot;: &quot;Hexviafind&quot;,
&quot;startDate&quot;: &quot;2010-04-27&quot;
}
]
} ]
</pre></div></div></div></div></div></div>
<div class="section">
<h2><a name="LIMIT_clauses"></a><a name="Limit_clauses" id="Limit_clauses">LIMIT clauses</a></h2>
<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>
<div class="section">
<div class="section">
<div class="section">
<h5><a name="Example"></a>Example</h5>
<div class="source">
<div class="source">
<pre> SELECT VALUE user
FROM GleambookUsers AS user
ORDER BY len(user.friendIds) DESC
LIMIT 1;
</pre></div></div>
<p>This query returns:</p>
<div class="source">
<div class="source">
<pre> [ {
&quot;userSince&quot;: &quot;2012-08-20T10:10:00.000Z&quot;,
&quot;friendIds&quot;: [
2,
3,
6,
10
],
&quot;gender&quot;: &quot;F&quot;,
&quot;name&quot;: &quot;MargaritaStoddard&quot;,
&quot;nickname&quot;: &quot;Mags&quot;,
&quot;alias&quot;: &quot;Margarita&quot;,
&quot;id&quot;: 1,
&quot;employment&quot;: [
{
&quot;organizationName&quot;: &quot;Codetechno&quot;,
&quot;start-date&quot;: &quot;2006-08-06&quot;
},
{
&quot;end-date&quot;: &quot;2010-01-26&quot;,
&quot;organizationName&quot;: &quot;geomedia&quot;,
&quot;start-date&quot;: &quot;2010-06-17&quot;
}
]
} ]
</pre></div></div></div></div></div></div>
<div class="section">
<h2><a name="WITH_clauses"></a><a name="With_clauses" id="With_clauses">WITH clauses</a></h2>
<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>
<div class="section">
<div class="section">
<div class="section">
<h5><a name="Example"></a>Example</h5>
<div class="source">
<div class="source">
<pre>WITH avgFriendCount AS (
SELECT VALUE AVG(ARRAY_COUNT(user.friendIds))
FROM GleambookUsers AS user
)[0]
SELECT VALUE user
FROM GleambookUsers user
WHERE ARRAY_COUNT(user.friendIds) &gt; avgFriendCount;
</pre></div></div>
<p>This query returns:</p>
<div class="source">
<div class="source">
<pre>[ {
&quot;userSince&quot;: &quot;2012-08-20T10:10:00.000Z&quot;,
&quot;friendIds&quot;: [
2,
3,
6,
10
],
&quot;gender&quot;: &quot;F&quot;,
&quot;name&quot;: &quot;MargaritaStoddard&quot;,
&quot;nickname&quot;: &quot;Mags&quot;,
&quot;alias&quot;: &quot;Margarita&quot;,
&quot;id&quot;: 1,
&quot;employment&quot;: [
{
&quot;organizationName&quot;: &quot;Codetechno&quot;,
&quot;start-date&quot;: &quot;2006-08-06&quot;
},
{
&quot;end-date&quot;: &quot;2010-01-26&quot;,
&quot;organizationName&quot;: &quot;geomedia&quot;,
&quot;start-date&quot;: &quot;2010-06-17&quot;
}
]
}, {
&quot;userSince&quot;: &quot;2012-07-10T10:10:00.000Z&quot;,
&quot;friendIds&quot;: [
1,
5,
8,
9
],
&quot;name&quot;: &quot;EmoryUnk&quot;,
&quot;alias&quot;: &quot;Emory&quot;,
&quot;id&quot;: 3,
&quot;employment&quot;: [
{
&quot;organizationName&quot;: &quot;geomedia&quot;,
&quot;endDate&quot;: &quot;2010-01-26&quot;,
&quot;startDate&quot;: &quot;2010-06-17&quot;
}
]
} ]
</pre></div></div>
<p>The query is equivalent to the following, more complex, inlined form of the query:</p>
<div class="source">
<div class="source">
<pre>SELECT *
FROM GleambookUsers user
WHERE ARRAY_COUNT(user.friendIds) &gt;
( SELECT VALUE AVG(ARRAY_COUNT(user.friendIds))
FROM GleambookUsers AS user
) [0];
</pre></div></div>
<p>WITH can be particularly useful when a value needs to be used several times in a query.</p>
<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>
<div class="section">
<h2><a name="LET_clauses"></a><a name="Let_clauses" id="Let_clauses">LET clauses</a></h2>
<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>
<div class="section">
<div class="section">
<div class="section">
<h5><a name="Example"></a>Example</h5>
<div class="source">
<div class="source">
<pre>SELECT u.name AS uname, messages AS messages
FROM GleambookUsers u
LET messages = (SELECT VALUE m
FROM GleambookMessages m
WHERE m.authorId = u.id)
WHERE EXISTS messages;
</pre></div></div>
<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>
<div class="source">
<div class="source">
<pre>[ {
&quot;uname&quot;: &quot;MargaritaStoddard&quot;,
&quot;messages&quot;: [
{
&quot;senderLocation&quot;: [
38.97,
77.49
],
&quot;inResponseTo&quot;: 1,
&quot;messageId&quot;: 11,
&quot;authorId&quot;: 1,
&quot;message&quot;: &quot; can't stand at&amp;t its plan is terrible&quot;
},
{
&quot;senderLocation&quot;: [
41.66,
80.87
],
&quot;inResponseTo&quot;: 4,
&quot;messageId&quot;: 2,
&quot;authorId&quot;: 1,
&quot;message&quot;: &quot; dislike iphone its touch-screen is horrible&quot;
},
{
&quot;senderLocation&quot;: [
37.73,
97.04
],
&quot;inResponseTo&quot;: 2,
&quot;messageId&quot;: 4,
&quot;authorId&quot;: 1,
&quot;message&quot;: &quot; can't stand at&amp;t the network is horrible:(&quot;
},
{
&quot;senderLocation&quot;: [
40.33,
80.87
],
&quot;inResponseTo&quot;: 11,
&quot;messageId&quot;: 8,
&quot;authorId&quot;: 1,
&quot;message&quot;: &quot; like verizon the 3G is awesome:)&quot;
},
{
&quot;senderLocation&quot;: [
42.5,
70.01
],
&quot;inResponseTo&quot;: 12,
&quot;messageId&quot;: 10,
&quot;authorId&quot;: 1,
&quot;message&quot;: &quot; can't stand motorola the touch-screen is terrible&quot;
}
]
}, {
&quot;uname&quot;: &quot;IsbelDull&quot;,
&quot;messages&quot;: [
{
&quot;senderLocation&quot;: [
31.5,
75.56
],
&quot;inResponseTo&quot;: 1,
&quot;messageId&quot;: 6,
&quot;authorId&quot;: 2,
&quot;message&quot;: &quot; like t-mobile its platform is mind-blowing&quot;
},
{
&quot;senderLocation&quot;: [
48.09,
81.01
],
&quot;inResponseTo&quot;: 4,
&quot;messageId&quot;: 3,
&quot;authorId&quot;: 2,
&quot;message&quot;: &quot; like samsung the plan is amazing&quot;
}
]
} ]
</pre></div></div>
<p>This query is equivalent to the following query that does not use the <tt>LET</tt> clause:</p>
<div class="source">
<div class="source">
<pre>SELECT u.name AS uname, ( SELECT VALUE m
FROM GleambookMessages m
WHERE m.authorId = u.id
) AS messages
FROM GleambookUsers u
WHERE EXISTS ( SELECT VALUE m
FROM GleambookMessages m
WHERE m.authorId = u.id
);
</pre></div></div></div></div></div></div>
<div class="section">
<h2><a name="UNION_ALL"></a><a name="Union_all" id="Union_all">UNION ALL</a></h2>
<p>UNION ALL can be used to combine two input streams 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>
<div class="section">
<div class="section">
<div class="section">
<h5><a name="Example"></a>Example</h5>
<div class="source">
<div class="source">
<pre>SELECT u.name AS uname
FROM GleambookUsers u
WHERE u.id = 2
UNION ALL
SELECT VALUE m.message
FROM GleambookMessages m
WHERE authorId=2;
</pre></div></div>
<p>This query returns:</p>
<div class="source">
<div class="source">
<pre>[
&quot; like t-mobile its platform is mind-blowing&quot;
, {
&quot;uname&quot;: &quot;IsbelDull&quot;
}, &quot; like samsung the plan is amazing&quot;
]
</pre></div></div></div></div></div></div>
<div class="section">
<h2><a name="Subqueries" id="Subqueries">Subqueries</a></h2>
<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>
<div class="section">
<div class="section">
<div class="section">
<h5><a name="Example"></a>Example</h5>
<div class="source">
<div class="source">
<pre>SELECT uid,
(SELECT VALUE m.msg
FROM msgs m
WHERE m.msg.message LIKE '%dislike%'
ORDER BY m.msg.messageId
LIMIT 2) AS msgs
FROM GleambookMessages message
GROUP BY message.authorId AS uid GROUP AS msgs(message AS msg);
</pre></div></div>
<p>For our sample data set, this query returns:</p>
<div class="source">
<div class="source">
<pre>[ {
&quot;msgs&quot;: [
{
&quot;senderLocation&quot;: [
41.66,
80.87
],
&quot;inResponseTo&quot;: 4,
&quot;messageId&quot;: 2,
&quot;authorId&quot;: 1,
&quot;message&quot;: &quot; dislike iphone its touch-screen is horrible&quot;
}
],
&quot;uid&quot;: 1
}, {
&quot;msgs&quot;: [
],
&quot;uid&quot;: 2
} ]
</pre></div></div>
<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>
<div class="section">
<h2><a name="SQL_vs._SQL-92"></a><a name="Vs_SQL-92" id="Vs_SQL-92">SQL++ vs. SQL-92</a></h2>
<p>SQL++ offers the following additional features beyond SQL-92 (hence the &#x201c;++&#x201d; in its name):</p>
<ul>
<li>Fully composable and functional: A subquery can iterate over any intermediate collection and can appear anywhere in a query.</li>
<li>Schema-free: The query language does not assume the existence of a static schema for any data that it processes.</li>
<li>Correlated FROM terms: A right-side FROM term expression can refer to variables defined by FROM terms on its left.</li>
<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>
<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>
</ul>
<p>The following matrix is a quick &#x201c;SQL-92 compatibility cheat sheet&#x201d; for SQL++.</p>
<table border="0" class="table table-striped">
<thead>
<tr class="a">
<th>Feature </th>
<th>SQL++ </th>
<th>SQL-92 </th>
<th>Why different? </th>
</tr>
</thead>
<tbody>
<tr class="b">
<td>SELECT * </td>
<td>Returns nested objects </td>
<td>Returns flattened concatenated objects </td>
<td>Nested collections are 1st class citizens </td>
</tr>
<tr class="a">
<td>SELECT list </td>
<td>order not preserved </td>
<td>order preserved </td>
<td>Fields in a JSON object is not ordered </td>
</tr>
<tr class="b">
<td>Subquery </td>
<td>Returns a collection </td>
<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>
<td>Nested collections are 1st class citizens </td>
</tr>
<tr class="a">
<td>LEFT OUTER JOIN </td>
<td>Fills in <tt>MISSING</tt>(s) for non-matches </td>
<td>Fills in <tt>NULL</tt>(s) for non-matches </td>
<td>&#x201c;Absence&#x201d; is more appropriate than &#x201c;unknown&#x201d; here. </td>
</tr>
<tr class="b">
<td>UNION ALL </td>
<td>Allows heterogeneous inputs and output </td>
<td>Input streams must be UNION-compatible and output field names are drawn from the first input stream </td>
<td>Heterogenity and nested collections are common </td>
</tr>
<tr class="a">
<td>IN constant_expr </td>
<td>The constant expression has to be an array or multiset, i.e., [..,..,&#x2026;] </td>
<td>The constant collection can be represented as comma-separated items in a paren pair </td>
<td>Nested collections are 1st class citizens </td>
</tr>
<tr class="b">
<td>String literal </td>
<td>Double quotes or single quotes </td>
<td>Single quotes only </td>
<td>Double quoted strings are pervasive </td>
</tr>
<tr class="a">
<td>Delimited identifiers </td>
<td>Backticks </td>
<td>Double quotes </td>
<td>Double quoted strings are pervasive </td>
</tr>
</tbody>
</table>
<p>The following SQL-92 features are not implemented yet. However, SQL++ does not conflict those features:</p>
<ul>
<li>CROSS JOIN, NATURAL JOIN, UNION JOIN</li>
<li>RIGHT and FULL OUTER JOIN</li>
<li>INTERSECT, EXCEPT, UNION with set semantics</li>
<li>CAST expression</li>
<li>NULLIF expression</li>
<li>COALESCE expression</li>
<li>ALL and SOME predicates for linking to subqueries</li>
<li>UNIQUE predicate (tests a collection for duplicates)</li>
<li>MATCH predicate (tests for referential integrity)</li>
<li>Row and Table constructors</li>
<li>DISTINCT aggregates</li>
<li>Preserved order for expressions in a SELECT list</li>
</ul>
<h1><a name="Errors" id="Errors">4. Errors</a></h1>
<p>A SQL++ query can potentially result in one of the following errors:</p>
<ul>
<li>syntax error,</li>
<li>identifier resolution error,</li>
<li>type error,</li>
<li>resource error.</li>
</ul>
<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>
<div class="section">
<h2><a name="Syntax_Errors"></a><a name="Syntax_errors" id="Syntax_errors">Syntax Errors</a></h2>
<p>An valid SQL++ query must satisfy the SQL++ grammar rules. Otherwise, a syntax error will be raised.</p>
<div class="section">
<div class="section">
<div class="section">
<h5><a name="Example"></a>Example</h5>
<div class="source">
<div class="source">
<pre>SELECT *
FROM GleambookUsers user
</pre></div></div>
<p>Since the ending semi-colon is mandatory for any SQL++ query, we will get a syntax error as follows:</p>
<div class="source">
<div class="source"