====== JSON Queries: A Tutorial ====== **NOTE:** This documentation is also available in the Evergreen documentation at http://docs.evergreen-ils.org/1.6/draft/html/. In github: http://github.com/rsoulliere/Evergreen-DocBook/blob/master/1.6/development/json.xml.
Equinox Software, Inc.
Licensing: Creative Commons Attribution-Share Alike 3.0 United States License.
Copyright © 2009 Equinox Software, Inc.
The json_query facility provides a way for client applications to query the database over the network. Instead of constructing its own SQL, the application encodes a query in the form of a JSON string and passes it to the json_query service. Then the json_query service parses the JSON, constructs and executes the corresponding SQL, and returns the results to the client application.
This arrangement enables the json_query service to act as a gatekeeper, protecting the database from potentially damaging SQL commands. In particular, the generated SQL is confined to SELECT statements, which will not change the contents of the database.
In addition, the json_query service sometimes uses its knowledge of the database structure to supply column names and join conditions so that the client application doesn't have to.
Nevertheless, the need to encode a query in a JSON string adds complications, because the client needs to know how to build the right JSON. JSON queries are also somewhat limiting -- they can't do all of the things that you can do with raw SQL.
This tutorial explains what you can do with a JSON query, and how you can do it.
A JSON query does not refer to tables and columns. Instead, it refers to classes and fields, which the IDL maps to the corresponding database entities.
The IDL (Interface Definition Language) is an XML file, typically
/openils/conf/fm_IDL.xml
. It maps each class to a table, view,
or subquery, and each field to a column. It also includes information about foreign
key relationships.
(The IDL also defines virtual classes and virtual fields, which don't correspond to database entities. We won't discuss them here, because json_query ignores them.)
When it first starts up, json_query loads a relevant subset of the IDL into memory. Thereafter, it consults its copy of the IDL whenever it needs to know about the database structure. It uses the IDL to validate the JSON queries, and to translate classes and fields to the corresponding tables and columns. In some cases it uses the IDL to supply information that the queries don't provide.
References to "SQL" refer to the dialect implemented by PostgreSQL. This tutorial assumes that you are already familiar with SQL.
You should also be familiar with JSON. However it is worth defining a couple of terms that have other meanings in other contexts:
An "object" is a JSON object, i.e. a comma-separated list of name:value pairs, enclosed in curly braces, like this:
{ "a":"frobozz", "b":24, "c":null }
An "array" is a JSON array, i.e. a comma-separated list of values, enclosed in square brackets, like this:
[ "Goober", 629, null, false, "glub" ]
The test_json_query utility generated the SQL for all of the sample queries in this tutorial. Newlines and indentation were then inserted manually for readability.
All examples involve the actor.org_unit table, sometimes in combination with a few related tables. The queries themselves are designed to illustrate the syntax, not to do anything useful at the application level. For example, it's not meaningful to take the square root of an org_unit id, except to illustrate how to code a function call. The examples are like department store mannequins -- they have no brains, they're only for display.
The simplest kind of query defines nothing but a FROM clause. For example:
{ "from":"aou" }
In this minimal example we select from only one table. Later we will see how to join multiple tables.
Since we don't supply a WHERE clause, json_query constructs a default WHERE clause for us, including all the available columns. The resulting SQL looks like this:
SELECT "aou".billing_address AS "billing_address", "aou".holds_address AS "holds_address", "aou".id AS "id", "aou".ill_address AS "ill_address", "aou".mailing_address AS "mailing_address", "aou".name AS "name", "aou".ou_type AS "ou_type", "aou".parent_ou AS "parent_ou", "aou".shortname AS "shortname", "aou".email AS "email", "aou".phone AS "phone", "aou".opac_visible AS "opac_visible" FROM actor.org_unit AS "aou" ;
The default SELECT clause includes every column that the IDL defines it as a non-virtual field for the class in question. If a column is present in the database but not defined in the IDL, json_query doesn't know about it. In the case of the example shown above, all the columns are defined in the IDL, so they all show up in the default SELECT clause.
If the FROM clause joins two or more tables, the default SELECT clause includes columns only from the core table, not from any of the joined tables.
The default SELECT clause has almost the same effect as "SELECT *
",
but not exactly. If you were to "SELECT * from actor.org_unit_type
in psql, the output would include all the same columns as in the example above, but not in
the same order. A default SELECT clause includes the columns in the order in which the IDL
defines them, which may be different from the order in which the database defines them.
In practice, the sequencing of columns in the SELECT clause is not significant. The result set is returned to the client program in the form of a data structure, which the client program can navigate however it chooses.
There are other ways to get a default SELECT clause. However, default SELECT clauses are a distraction at this point, because most of the time you'll specify your own SELECT clause explicitly, as we will discuss later.
Let's consider some more important aspects of this simple example -- more important because they apply to more complex queries as well.
The entire JSON query is an object. In this simple case the object includes only one entry, for the FROM clause. Typically you'll also have entries for the SELECT clause and the WHERE clause, and possibly for HAVING, ORDER BY, LIMIT, or OFFSET clauses. There is no separate entry for a GROUP BY clause, which you can specify by other means.
Although all the other entries are optional, you must include an entry for the FROM clause. You cannot, for example, do a SELECT USER the way you can in psql.
Every column is qualified by an alias for the table. This alias is always the class name for the table, as defined in the IDL.
Every column is aliased with the column name. There is a way to choose a different column alias (not shown here).
The following variation also produces a default SELECT clause:
{ "from":"aou", "select": { "aou":"*" } }
...and so does this one:
{ "select": { "aou":null }, "from":"aou" }
While this syntax may not be terribly useful, it does illustrate the minimal structure
of a SELECT clause in a JSON query: an entry in the outermost JSON object, with a key of
"select"
. The value associated with this key is another JSON object,
whose keys are class names.
(These two examples also illustrate another point: unlike SQL, a JSON query doesn't care whether the FROM clause or the SELECT clause comes first.)
Usually you don't want the default SELECT clause. Here's how to select only some of the columns:
{ "from":"aou", "select": { "aou":[ "id", "name" ] } }
The value associated with the class name is an array of column names. If you select columns from multiple tables (not shown here), you'll need a separate entry for each table, and a separate column list for each entry.
The previous example results in the following SQL:
SELECT "aou".id AS "id", "aou".name AS "name" FROM actor.org_unit AS "aou" ;
The previous example featured an array of column names. More generally, it featured an array of field specifications, and one kind of field specification is a column name. The other kind is a JSON object, with some combination of the following keys:
"column"
-- the column name (required).
"alias"
-- used to define a column alias, which
otherwise defaults to the column name.
"aggregate"
-- takes a value of
true
or false.
Don't worry about
this one yet. It concerns the use of GROUP BY clauses, which we will
examine later.
"transform"
-- the name of an SQL function to be
called.
"result_field"
-- used with
"transform"
; specifies an output column of a function that
returns multiple columns at a time.
"params"
-- used with "transform"
;
provides a list of parameters for the function. They may be strings, numbers,
or nulls.
This example assigns a different column alias:
{ "from":"aou", "select": { "aou": [ "id", { "column":"name", "alias":"org_name" } ] } }
SELECT "aou".id AS "id", "aou".name AS "org_name" FROM actor.org_unit AS "aou" ;
In this case, changing the column alias doesn't accomplish much. But if we were joining to the actor.org_unit_type table, which also has a "name" column, we could use different aliases to distinguish them.
The following example uses a function to raise a column to upper case:
{ "from":"aou", "select": { "aou": [ "id", { "column":"name", "transform":"upper" } ] } }
SELECT "aou".id AS "id", upper("aou".name ) AS "name" FROM actor.org_unit AS "aou" ;
Here we take a substring of the name, using the "params"
element to pass parameters:
{ "from":"aou", "select": { "aou": [ "id", { "column":"name", "transform":"substr", "params":[ 3, 5 ] } ] } }
SELECT "aou".id AS "id", substr("aou".name,'3','5' ) AS "name" FROM actor.org_unit AS "aou" ;
The parameters specified with "params"
are inserted
after the applicable column ("name"
in this
case), which is always the first parameter. They are always passed as strings,
i.e. enclosed in quotes, even if the JSON expresses them as numbers. PostgreSQL
will ordinarily coerce them to the right type. However if the function name is
overloaded to accept different types, PostgreSQL may invoke a function other than
the one intended.
Finally we call a fictitious function "frobozz"
that returns
multiple columns, where we want only one of them:
{ "from":"aou", "select": { "aou": [ "id", { "column":"name", "transform":"frobozz", "result_field":"zamzam" } ] } }
SELECT "aou".id AS "id", (frobozz("aou".name ))."zamzam" AS "name" FROM actor.org_unit AS "aou" ;
The "frobozz" function doesn't actually exist, but json_query doesn't know that. The query won't fail until json_query tries to execute it in the database.
You can do some things in a SELECT clause with raw SQL (with psql, for example) that you can't do with a JSON query. Some of them matter and some of them don't.
When you do a JOIN, you can't arrange the selected columns in any arbitrary sequence, because all of the columns from a given table must be grouped together. This limitation doesn't matter. The results are returned in the form of a data structure, which the client program can navigate however it likes.
You can't select an arbitrary expression, such as
"percentage / 100"
or "last_name || ', ' || first_name"
.
Most of the time this limitation doesn't matter either, because the client program
can do these kinds of manipulations for itself. However, function calls may be a problem.
You can't nest them, and you can't pass more than one column value to them (and it has
to be the first parameter).
You can't use a CASE expression. Instead, the client application can do the equivalent branching for itself.
You can't select a subquery. In raw SQL you can do something like the following:
SELECT id, name, ( SELECT name FROM actor.org_unit_type AS aout WHERE aout.id = aou.ou_type ) AS type_name FROM actor.org_unit AS aou;
This contrived example is not very realistic. Normally you would use a JOIN in this case, and that's what you should do in a JSON query. Other cases may not be so easy to solve.
Most queries need a WHERE clause, as in this simple example:
{ "from":"aou", "select": { "aou":[ "id", "name" ] }, "where": { "parent_ou":"3" } }
Like the SELECT clause, the WHERE clause gets its own entry in the top-level object
of a JSON query. The key is "where"
, and the associated value is
either an object (as shown here) or an array (to be discussed a bit later). Each entry
in the object is a separate condition.
In this case, we use a special shortcut for expressing an equality condition. The column name is on the left of the colon, and the value to which we are equating it is on the right.
Here's the resulting SQL:
SELECT "aou".id AS "id", "aou".name AS "name" FROM actor.org_unit AS "aou" WHERE "aou".parent_ou = 3;
Like the SELECT clause, the generated WHERE clause qualifies each column name with the alias of the relevant table.
If you want to compare a column to NULL, put "null
" (without
quotation marks) to the right of the colon instead of a literal value. The resulting
SQL will include "IS NULL"
instead of an equals sign.
Here's the same query (which generates the same SQL) without the special shortcut:
{ "from":"aou", "select": { "aou":[ "id", "name" ] }, "where": { "parent_ou":{ "=":3 } } }
We still have an entry whose key is the column name, but this time the associated value is another JSON object. It must contain exactly one entry, with the comparison operator on the left of the colon, and the value to be compared on the right.
The same syntax works for other kinds of comparison operators. For example:
{ "from":"aou", "select": { "aou":[ "id", "name" ] }, "where": { "parent_ou":{ ">":3 } } }
...turns into:
SELECT "aou".id AS "id", "aou".name AS "name" FROM actor.org_unit AS "aou" WHERE "aou".parent_ou > 3 ;
The condition '"=":null
' turns into IS NULL. Any other
operator used with "null"
turns into IS NOT NULL.
You can use most of the comparison operators recognized by PostgreSQL:
= <> != < > <= >= ~ ~* !~ !~* like ilike similar to
The only ones you can't use are "is distinct from"
and
"is not distinct from"
.
Here's a dirty little secret: json_query doesn't really pay much attention to the
operator you supply. It merely checks to make sure that the operator doesn't contain
any semicolons or white space, in order to prevent certain kinds of SQL injection.
It also allows "similar to"
as a special exception.
As a result, you can slip an operator of your own devising into the SQL, so long as it doesn't contain any semicolons or white space, and doesn't create invalid syntax. Here's a contrived and rather silly example:
{ "from":"aou", "select": { "aou":[ "id", "name" ] }, "where": { "parent_ou":{ "<2+":3 } } }
...which results in the following SQL:
SELECT "aou".id AS "id", "aou".name AS "name" FROM actor.org_unit AS "aou" WHERE "aou".parent_ou <2+ 3;
It's hard to come up with a realistic case where this hack would be useful, but it could happen.
Here's how to put another column on the right hand side of a comparison:
{ "from":"aou", "select": { "aou":[ "id", "name" ] }, "where": { "id": { ">": { "+aou":"parent_ou" } } } };
This syntax is similar to the previous examples, except that instead of comparing to a literal value, we compare to an object. This object has only a single entry, whose key is a table alias preceded by a leading plus sign. The associated value is the name of the column.
Here's the resulting SQL:
SELECT "aou".id AS "id", "aou".name AS "name" FROM actor.org_unit AS "aou" WHERE ( "aou".id > ( "aou".parent_ou ) );
The table alias must correspond to the appropriate table. Since json_query doesn't validate the choice of alias, it won't detect an invalid alias until it tries to execute the query. In this simple example there's only one table to choose from. The choice of alias is more important in a subquery or join.
The leading plus sign, combined with a table alias, can be used in other situations to designate the table to which a column belongs. We shall defer a discussion of this usage to the section on joins.
In SQL, there are several ways to test a boolean column such as actor.org_unit.opac_visible. The most obvious way is to compare it to true or false:
SELECT id FROM actor.org_unit WHERE opac_visible = true;
In a JSON query this approach doesn't work. If you try it, the "= true" test will turn into IS NULL. Don't do that. Instead, use a leading plus sign, as described in the preceding section, to treat the boolean column as a stand-alone condition:
{ "from":"aou", "select": { "aou":[ "id" ] }, "where": { "+aou":"opac_visible" } }
Result:
SELECT "aou".id AS "id" FROM actor.org_unit AS "aou" WHERE "aou".opac_visible ;
If you need to test for falsity, then write a test for truth and negate it with the
"-not"
operator. We will discuss the "-not" operator later, but
here's a preview:
{ "from":"aou", "select": { "aou":[ "id" ] }, "where": { "-not": { "+aou":"opac_visible" } } }
SELECT "aou".id AS "id" FROM actor.org_unit AS "aou" WHERE NOT ( "aou".opac_visible );
You can also compare a boolean column directly to a more complex condition:
{ "from":"aou", "select": { "aou":[ "id" ] }, "where": { "opac_visible": { "=": { "parent_ou":{ ">":3 } } } } }
Here we compare a boolean column, not to a literal value, but to a boolean expression. The resulting SQL looks a little goofy, but it works:
SELECT "aou".id AS "id" FROM actor.org_unit AS "aou" WHERE ( "aou".opac_visible = ( "aou".parent_ou > 3 ) );
In this case we compare the boolean column to a single simple condition. However you can include additional complications -- multiple conditions, IN lists, BETWEEN clauses, and other features as described below.
If you need multiple conditions, just add them to the "where"
object, separated by commas:
{ "from":"aou", "select": { "aou":[ "id", "name" ] }, "where": { "parent_ou":{ ">":3 }, "id":{ "<>":7 } } }
The generated SQL connects the conditions with AND:
SELECT "aou".id AS "id", "aou".name AS "name" FROM actor.org_unit AS "aou" WHERE "aou".parent_ou > 3 AND "aou".id <> 7;
Later we will see how to use OR instead of AND.
Here's a puzzler. Suppose you need two conditions for the same column. How do you code them in the same WHERE clause? For example, suppose you want something like this:
SELECT id, name FROM actor.org_unit WHERE parent_ou > 3 AND parent_ou <> 7;
You might try a WHERE clause like this:
"where": { "parent_ou":{ ">":3 }, "parent_ou":{ "<>":7 } }
Nope. Won't work. According to JSON rules, two entries in the same object can't have the same key.
After slapping yourself in the forehead, you try something a little smarter:
"where": { "parent_ou": { ">":3, "<>":7 } }
Nice try, but that doesn't work either. Maybe it ought to work -- at least it's legal JSON -- but, no.
Here's what works:
{ "from":"aou", "select": { "aou":[ "id", "name" ] }, "where": [ { "parent_ou":{ ">":3 } }, { "parent_ou":{ "<>":7 } } ] }
We wrapped the two conditions into two separate JSON objects, and then wrapped those objects together into a JSON array. The resulting SQL looks like this:
SELECT "aou".id AS "id", "aou".name AS "name FROM actor.org_unit AS "aou" WHERE ( "aou".parent_ou > 3 ) AND ( "aou".parent_ou <> 7 );
That's not quite what we were hoping for, because the extra parentheses are so ugly. But they're harmless. This will do.
If you're in the mood, you can use arrays to as many parentheses as you like, even if there is only one condition inside:
{ "from":"aou", "select": { "aou":[ "id", "name" ] }, "where": [[[[[[ { "parent_ou":{ ">":3 } }, ]]]]]] }
...yields:
SELECT "aou".id AS "id", "aou".name AS "name" FROM actor.org_unit AS "aou" WHERE ( ( ( ( ( ( "aou".parent_ou > 3 ) ) ) ) ) );
By default, json_query combines conditions with AND. When you need OR, here's how to do it:
{ "from":"aou", "select": { "aou":[ "id", "name" ] }, "where": { "-or": { "id":2, "parent_ou":3 } } }
We use "-or"
as the key, with the conditions to be ORed in an
associated object. The leading minus sign is there to make sure that the operator
isn't confused with a column name. Later we'll see some other operators with leading
minus signs. In a couple of spots we even use plus signs.
Here are the results from the above example:
SELECT "aou".id AS "id", "aou".name AS "name" FROM actor.org_unit AS "aou" WHERE ( "aou".id = 2 OR "aou".parent_ou = 3 );
The conditions paired with "-or"
are linked by OR and enclosed
in parentheses,
Here's how to do the same thing using an array, except that it produces an extra layer of parentheses:
{ "from":"aou", "select": { "aou":[ "id", "name" ] }, "where": { "-or": [ { "id":2 }, { "parent_ou":3 } ] } }
SELECT "aou".id AS "id", "aou".name AS "name" FROM actor.org_unit AS "aou" WHERE ( ( "aou".id = 2 ) OR ( "aou".parent_ou = 3 ) );
It's possible, though not very useful, to have only a single condition subject to
the "-or"
operator. In that case, the condition appears by itself,
since there's nothing to OR it to. This trick is another way to add an extraneous
layer of parentheses,
You can also use the "-and"
operator. It works just like
"-or"
, except that it combines conditions with AND instead of OR.
Since AND is the default, we don't usually need a separate operator for it, but it's
available.
In rare cases, nothing else will do -- you can't include two conditions in the same list because of the duplicate key problem, but you can't combine them with arrays either. In particular, you might need to combine them within an expression that you're comparing to a boolean column (see the subsection above on Testing Boolean Columns).
The "-not"
operator negates a condition or set of conditions.
For example:
{ "from":"aou", "select": { "aou":[ "id", "name" ] }, "where": { "-not": { "id":{ ">":2 }, "parent_ou":3 } } }
SELECT "aou".id AS "id", "aou".name AS "name" FROM actor.org_unit AS "aou" WHERE NOT ( "aou".id > 2 AND "aou".parent_ou = 3 );
In this example we merely negate a combination of two comparisons. However the
condition to be negated may be as complicated as it needs to be. Anything that can
be subject to "where"
can be subject to
"-not"
.
In most cases you can achieve the same result by other means. However the
"-not"
operator is the only way to represent NOT BETWEEN
(to be discussed later).
Two other operators carry a leading minus sign: "-exists"
and its negation "-not-exists"
. These operators apply to
subqueries, which have the same format as a full query. For example:
{ "from":"aou", "select": { "aou":[ "id", "name" ] }, "where": { "-exists": { "from":"asv", "select":{ "asv":[ "id" ] }, "where": { "owner":7 } } } }
SELECT "aou".id AS "id", "aou".name AS "name" FROM actor.org_unit AS "aou" WHERE EXISTS ( SELECT "asv".id AS "id" FROM action.survey AS "asv" WHERE "asv".owner = 7 );
This kind of subquery is of limited use, because its WHERE clause doesn't have anything to do with the main query. It just shuts down the main query altogether if it isn't satisfied.
More typical is a correlated subquery, whose WHERE clause refers to a row from the main query. For example:
{ "from":"aou", "select": { "aou":[ "id", "name" ] }, "where": { "-exists": { "from":"asv", "select":{ "asv":[ "id" ] }, "where": { "owner":{ "=":{ "+aou":"id" }} } } } }
Note the use of "+aou"
to qualify the id column in the
inner WHERE clause.
SELECT "aou".id AS "id", "aou".name AS "name" FROM actor.org_unit AS "aou" WHERE EXISTS ( SELECT "asv".id AS "id" FROM action.survey AS "asv" WHERE ("asv".owner = ( "aou".id )) );
This latter example illustrates the syntax, but in practice, it would probably be more natural to use an IN clause with a subquery (to be discussed later).
Here's how to express a BETWEEN clause:
{ "from":"aou", "select": { "aou":[ "id" ] }, "where": { "parent_ou": { "between":[ 3, 7 ] } } }
The value associated with the column name is an object with a single
entry, whose key is "between"
. The corresponding
value is an array with exactly two values, defining the range to be
tested.
The range bounds must be either numbers or string literals. Although SQL allows them to be null, a null doesn't make sense in this context, because a null never matches anything. Consequently json_query doesn't allow them.
The resulting SQL is just what you would expect:
SELECT "aou".id AS "id" FROM actor.org_unit AS "aou" WHERE parent_ou BETWEEN '3' AND '7';
There are two ways to code an IN list. One way is simply to include the list of values in an array:
{ "from":"aou", "select": { "aou":[ "id", "name" ] }, "where": { "parent_ou": [ 3, 5, 7 ] } }
As with a BETWEEN clause, the values in the array must be numbers or string literals. Nulls aren't allowed. Here's the resulting SQL, which again is just what you would expect:
SELECT "aou".id AS "id", "aou".name AS "name" FROM actor.org_unit AS "aou" WHERE "aou".parent_ou IN (3, 5, 7);
The other way is similar to the syntax shown above for a BETWEEN clause, except that the array may include any non-zero number of values:
{ "from":"aou", "select": { "aou":[ "id", "name" ] }, "where": { "parent_ou": { "in": [ 3, 5, 7 ] } } }
This version results in the same SQL as the first one.
For a NOT IN list, you can use the latter format, using the
"not in"
operator instead of "in"
.
Alternatively, you can use either format together with the
"-not"
operator.
For an IN clause with a subquery, the syntax is similar to the second
of the two formats for an IN list (see the previous subsection). The
"in"
or "not in"
operator is paired,
not with an array of values, but with an object representing the subquery.
For example:
{ "from":"aou", "select": { "aou":[ "id", "name" ] }, "where": { "id": { "in": { "from":"asv", "select":{ "asv":[ "owner" ] }, "where":{ "name":"Voter Registration" } } } } }
The results:
SELECT "aou".id AS "id", "aou".name AS "name" FROM actor.org_unit AS "aou" WHERE "aou".id IN ( SELECT "asv".owner AS "owner" FROM action.survey AS "asv" WHERE "asv".name = 'Voter Registration' );
In SQL the subquery may select multiple columns, but in a JSON query it can select only a single column.
For a NOT IN clause with a subquery, use the "not in"
operator instead of "in"
.
Here's how to compare a column to a function call:
{ "from":"aou", "select": { "aou":[ "id", "name" ] }, "where": { "id":{ ">":[ "sqrt", 16 ] } } }
A comparison operator (">"
in this case) is paired
with an array. The first entry in the array must be a string giving the name
of the function. The remaining parameters, if any, are the parameters. They
may be strings, numbers, or nulls. The resulting SQL for this example:
SELECT "aou".id AS "id", "aou".name AS "name" FROM actor.org_unit AS "aou" WHERE "aou".id > sqrt( '16' );
All parameters are passed as quoted strings -- even if, as in this case, they are really numbers.
This syntax is somewhat limited in that the function parameters must be constants (hence the use of a silly example).
In the discussion of the SELECT clause, we saw how you could transform the value of a selected column by passing it to a function. In the WHERE clause, you can use similar syntax to transform the value of a column before comparing it to something else.
For example:
{ "from":"aou", "select": { "aou":[ "id", "name" ] }, "where": { "name": { "=": { "transform":"upper", "value":"CARTER BRANCH" } } } }
The "transform"
entry gives the name of the function that we
will use on the left side of the comparison. The "value"
entry
designates the value on the right side of the comparison.
SELECT "aou".id AS "id", "aou".name AS "name" FROM actor.org_unit AS "aou" WHERE upper("aou".name ) = 'CARTER BRANCH' ;
As in the SELECT clause, you can pass literal values or nulls to the function
as additional parameters by using an array tagged as
"params"
:
{ "from":"aou", "select": { "aou":[ "id", "name" ] }, "where": { "name": { "=": { "transform":"substr", "params":[ 1, 6 ], "value":"CARTER" } } } }
SELECT "aou".id AS "id", "aou".name AS "name" FROM actor.org_unit AS "aou" WHERE substr("aou".name,'1','6' ) = 'CARTER' ;
The first parameter is always the column name, qualified by the class name, followed by any additional parameters (which are always enclosed in quotes even if they are numeric).
As in the SELECT clause: if the function returns multiple columns, you can specify
the one you want by using a "result_field"
entry (not shown
here).
If you leave out the "transform"
entry (or misspell it), the
column name will appear on the left without any function call. This syntax works,
but it's more complicated than it needs to be.
If you want to compare one function call to another, you can use the same syntax
shown in the previous subsection -- except that the "value"
entry
carries an array instead of a literal value. For example:
{ "from":"aou", "select": { "aou":[ "id", "name" ] }, "where": { "id": { ">": { "transform":"factorial", "value":[ "sqrt", 1000 ] } } } }
SELECT "aou".id AS "id", "aou".name AS "name" FROM actor.org_unit AS "aou" WHERE factorial("aou".id ) > sqrt( '1000' ) ;
The format for the right side function is similar to what we saw earlier, in the subsection Comparing to a Function. Note that there are two different formats for defining function calls:
For a function call to the left of the comparison, the function name is
tagged as "transform"
. The first parameter is always the
relevant column name; additional parameters, if any, are in an array tagged
as "params"
. The entry for
"result_field"
, if present, specifies a subcolumn.
For a function call to the right of the comparison, the function name is the first entry in an array, together with any parameters. There's no way to specify a subcolumn.
So far we have seen two kinds of data for the "value"
tag. A
string or number translates to a literal value, and an array translates to a function
call. The third possibility is a JSON object, which translates to a condition. For
example:
{ "from":"aou", "select": { "aou":[ "id", "name" ] }, "where": { "id": { "=": { "value":{ "parent_ou":{ ">":3 } }, "transform":"is_prime" } } } }
The function tagged as "transform"
must return boolean, or else
json_query will generate invalid SQL. The function used here,
"is_prime"
, is fictitious.
SELECT "aou".id AS "id", "aou".name AS "name" FROM actor.org_unit AS "aou" WHERE ( is_prime("aou".id ) = ( "aou".parent_ou > 3 ) );
If we left out the "transform"
entry, json_query would compare
the column on the left (which would to be boolean) to the condition on the right.
The results are similar to those for a simpler format described earlier (see the
subsection Testing Boolean Columns).
In the example above we compared the boolean to a simple condition. However the expression on the right may include multiple conditions, IN lists, subqueries, and whatever other complications are necessary.
The WHERE clause is subject to some of the same limitations as the SELECT clause. However, in the WHERE clause these limitations are more limiting, because the client program can't compensate by doing some of the work for itself.
You can't use arbitrary expressions in a WHERE condition, such as
"WHERE id > parent_ou -- 3"
. In some cases you may be able to
contrive a custom operator in order to fake such an expression. However this mechanism
is neither very general nor very aesthetic.
To the right of a comparison operator, all function parameters must be literals or null. You can't pass a column value, nor can you nest function calls.
Likewise you can't include column values or arbitrary expressions in an IN list or a BETWEEN clause.
You can't include null values in an IN list or a BETWEEN list, not that you should ever want to.
As noted earlier: you can't use the comparison operators
"is distinct from"
or "is not distinct from"
.
Also as noted earlier: a subquery in an IN clause cannot select more than one column.
Until now, our examples have selected from only one table at a time. As a result, the FROM clause has been very simple -- just a single string containing the class name of the relevant table.
When the FROM clause joins multiple tables, the corresponding JSON naturally gets more complicated.
SQL provides two ways to define a join. One way is to list both tables in the FROM clause, and put the join conditions in the WHERE clause:
SELECT aou.id, aout.name FROM actor.org_unit aou, actor.org_unit_type aout WHERE aout.id = aou.ou_type;
The other way is to use an explicit JOIN clause:
SELECT aou.id, aout.name FROM actor.org_unit aou JOIN actor.org_unit_type aout ON ( aout.id = aou.ou_type );
JSON queries use only the second of these methods. The following example expresses the same query in JSON:
{ "select": { "aou":[ "id" ], "aout":[ "name" ] }, "from": { "aou":"aout" } }
First, let's review the SELECT clause. Since it selects rows from two different tables,
the data for "select"
includes two entries, one for each table.
As for the FROM clause, it's no longer just a string. It's a JSON object, with exactly one entry. The key of this entry is the class name of the core table, i.e. the table named immediately after the FROM keyword. The data associated with this key contains the rest of the information about the join. In this simple example, that information consists entirely of a string containing the class name of the other table.
So where is the join condition?
It's in the IDL. Upon reading the IDL, json_query knows that actor.org_unit has a foreign key pointing to actor.org_unit_type, and builds a join condition accordingly:
SELECT "aou".id AS "id", "aout".name AS "name" FROM actor.org_unit AS "aou" INNER JOIN actor.org_unit_type AS "aout" ON ( "aout".id = "aou".ou_type ) ;
In this case the core table is the child table, and the joined table is the parent table. We could just as well have written it the other way around:
{ "select": { "aou":[ "id" ], "aout":[ "name" ] }, "from": { "aout":"aou" } }
SELECT "aou".id AS "id", "aout".name AS "name" FROM actor.org_unit_type AS "aout" INNER JOIN actor.org_unit AS "aou" ON ( "aou".ou_type = "aout".id ) ;
While it's convenient to let json_query pick the join columns, it doesn't always work.
For example, the actor.org_unit table has four different address ids, for four different kinds of addresses. Each of them is a foreign key to the actor.org_address table. Json_query can't guess which one you want if you don't tell it.
(Actually it will try to guess. It will pick the first matching link that it finds in the IDL, which may or may not be the one you want.)
Here's how to define exactly which columns you want for the join:
{ "select": { "aou":[ "id" ], "aoa":[ "street1" ] }, "from": { "aou": { "aoa": { "fkey":"holds_address", "field":"id" } } } }
Before, the table we were joining was represented merely by its class name. Now it's represented by an entry in a JSON object. The key of that entry is the class name, and the associated data is another layer of JSON object containing the attributes of the join.
Later we'll encounter other kinds of join attributes. For now, the only
attributes that we're looking at are the ones that identify the join columns:
"fkey"
and "field"
. The hard part is
remembering which is which:
"fkey"
identifies the join column from the
left table;
"field"
identifies the join column from the
right table.
When there are only two tables involved, the core table is on the left, and the non-core table is on the right. In more complex queries neither table may be the core table.
Here is the result of the preceding JSON:
SELECT "aou".id AS "id", "aoa".street1 AS "street1" FROM actor.org_unit AS "aou" INNER JOIN actor.org_address AS "aoa" ON ( "aoa".id = "aou".holds_address ) ;
In this example the child table is on the left and the parent table is on the right. We can swap the tables if we swap the join columns as well:
{ "select": { "aou":[ "id" ], "aoa":[ "street1" ] }, "from": { "aoa": { "aou": { "fkey":"id", "field":"holds_address" } } } }
SELECT "aou".id AS "id", "aoa".street1 AS "street1" FROM actor.org_address AS "aoa" INNER JOIN actor.org_unit AS "aou" ON ( "aou".holds_address = "aoa".id ) ;
When you specify both of the join columns, json_query assumes that you know what you're doing. It doesn't check the IDL to confirm that the join makes sense. The burden is on you to avoid absurdities.
We just saw how to specify both ends of a join. It turns out that there's a shortcut -- most of the time you only need to specify one end. Consider the following variation on the previous example:
{ "select": { "aou":[ "id" ], "aoa":[ "street1" ] }, "from": { "aoa": { "aou": { "field":"holds_address" } } } }
..which results in exactly the same SQL as before.
Here we specified the join column from the child table, the column that is a foreign key pointing to another table. As long as that linkage is defined in the IDL, json_query can look it up and figure out what the corresponding column is in the parent table.
However this shortcut doesn't work if you specify only the column in the parent table, because it would lead to ambiguities. Suppose we had specified the id column of actor.org_address. As noted earlier, there are four different foreign keys from actor.org_unit to actor.org_address, and json_query would have no way to guess which one we wanted.
So far we have joined only two tables at a time. What if we need to join one table to two different tables?
Here's an example:
{ "select": { "aou":[ "id" ], "aout":[ "depth" ], "aoa":[ "street1" ] }, "from": { "aou": { "aout":{}, "aoa": { "fkey":"holds_address" } } } }
The first join, to actor.org_unit_type, is simple. We could have specified join columns, but we don't have to, because json_query will construct that join on the basis of what it finds in the IDL. Having no join attributes to specify, we leave that object empty.
For the second join, to actor.org_address, we have to specify at least the join column in the child table, as discussed earlier. We could also have specified the join column from the parent table, but we don't have to, so we didn't.
Here is the resulting SQL:
SELECT "aou".id AS "id", "aout".depth AS "depth", "aoa".street1 AS "street1" FROM actor.org_unit AS "aou" INNER JOIN actor.org_unit_type AS "aout" ON ( "aout".id = "aou".ou_type ) INNER JOIN actor.org_address AS "aoa" ON ( "aoa".id = "aou".holds_address ) ;
Since there can be only one core table, the outermost object in the FROM clause can have only one entry, whose key is the class name of the core table. The next level has one entry for every table that's joined to the core table.
Let's look at that last query again. It joins three tables, and the core table is the one in the middle. Can we make one of the end tables the core table instead?
Yes, we can:
{ "select": { "aou":[ "id" ], "aout":[ "depth" ], "aoa":[ "street1" ] }, "from": { "aoa": { "aou": { "field":"holds_address", "join": { "aout":{ "fkey":"ou_type" } } } } } }
The "join"
attribute introduces another level of join. In this
case "aou"
is the left table for the nested join, and the right table
for the original join. Here are the results:
SELECT "aou".id AS "id", "aout".depth AS "depth", "aoa".street1 AS "street1" FROM actor.org_address AS "aoa" INNER JOIN actor.org_unit AS "aou" ON ( "aou".holds_address = "aoa".id ) INNER JOIN actor.org_unit_type AS "aout" ON ( "aout".id = "aou".ou_type ) ;
By default, json_query constructs an inner join. If you need an outer join, you can add the join type as an attribute of the join:
{ "select": { "aou":[ "id" ], "aoa":[ "street1" ] }, "from": { "aoa": { "aou": { "field":"mailing_address", "type":"left" } } } }
Here we asked for a left outer join. For a right outer join, code
"type":"right"
. For a full outer join, code
"type":"full"
. Any other value for "type" results in an inner
join, so watch out for typos. A type of "rihgt"
will give you
a wrong join instead of a right one.
Here is the resulting SQL for this example:
SELECT "aou".id AS "id", "aoa".street1 AS "street1" FROM actor.org_address AS "aoa" LEFT JOIN actor.org_unit AS "aou" ON ( "aou".mailing_address = "aoa".id ) ;
In the WHERE clause of the generated SQL, every column name is qualified by a table alias, which is always the corresponding class name.
If a column belongs to the core table, this qualification happens by default. If it belongs to a joined table, the JSON must specify what class name to use for an alias. For example:
{ "select": { "aou":[ "id" ], "aout":[ "name" ] }, "from": { "aout":"aou" }, "where": { "+aou":{ "parent_ou":2 } } }
Note the peculiar operator "+aou"
-- a plus sign followed
by the relevant class name. This operator tells json_query to apply the specified
class to the condition that follows. The result:
SELECT "aou".id AS "id", "aout".name AS "name" FROM actor.org_unit_type AS "aout" INNER JOIN actor.org_unit AS "aou" ON ( "aou".ou_type = "aout".id ) WHERE ( "aou".parent_ou = 2 );
The plus-class operator may apply to multiple conditions:
{ "select": { "aou":[ "id" ], "aout":[ "name" ] }, "from": { "aout":"aou" }, "where": { "+aou":{ "parent_ou":2, "id":{ "<":42 } } } }
SELECT "aou".id AS "id", "aout".name AS "name" FROM actor.org_unit_type AS "aout" INNER JOIN actor.org_unit AS "aou" ON ( "aou".ou_type = "aout".id ) WHERE ( "aou".parent_ou = 2 AND "aou".id < 42 );
For these artificial examples, it would have been simpler to swap the tables, so that actor.org_unit is the core table. Then you wouldn't need to go through any special gyrations to apply the right table alias. In a more realistic case, however, you might need to apply conditions to both tables. Just swapping the tables wouldn't solve the problem.
You can also use a plus-class operator to compare columns from two different tables:
{ "select": { "aou":[ "id" ], "aout":[ "name" ] }, "from": { "aout":"aou" }, "where": { "depth": { ">": { "+aou":"parent_ou" } } } }
SELECT "aou".id AS "id", "aout".name AS "name" FROM actor.org_unit_type AS "aout" INNER JOIN actor.org_unit AS "aou" ON ( "aou".ou_type = "aout".id ) WHERE ( "aout".depth > ( "aou".parent_ou ) );
Please don't expect that query to make any sense. It doesn't. But it illustrates the syntax.
While the above approach certainly works, the special syntax needed is goofy and awkward. A somewhat cleaner solution is to include a condition in the JOIN clause:
{ "select": { "aou":[ "id" ], "aout":[ "name" ] }, "from": { "aout": { "aou": { "filter": { "parent_ou":2 } } } } }
SELECT "aou".id AS "id", "aout".name AS "name" FROM actor.org_unit_type AS "aout" INNER JOIN actor.org_unit AS "aou" ON ( "aou".ou_type = "aout".id AND "aou".parent_ou = 2 ) ;
By default, json_query uses AND to combine the "filter"
condition with the original join condition. If you need OR, you can use the
"filter_op"
attribute to say so:
{ "select": { "aou":[ "id" ], "aout":[ "name" ] }, "from": { "aout": { "aou": { "filter": { "parent_ou":2 }, "filter_op":"or" } } } }
SELECT "aou".id AS "id", "aout".name AS "name" FROM actor.org_unit_type AS "aout" INNER JOIN actor.org_unit AS "aou" ON ( "aou".ou_type = "aout".id OR "aou".parent_ou = 2 ) ;
If the data tagged by "filter_op"
is anything but
"or"
(in upper, lower, or mixed case), json_query uses AND
instead of OR.
The condition tagged by "filter"
may be much more complicated.
In fact it accepts all the same syntax as the WHERE clause.
Remember, though, that it all gets combined with the the original join condition with an AND, or with an OR if you so specify. If you're not careful, the result may be a confusing mixture of AND and OR at the same level.
In SQL you can put a subquery in a FROM clause, and select from it as if it were a table. A JSON query has no way to do that directly. The IDL, however, can define a class as a subquery instead of as a table. When you SELECT from it, json_query inserts the corresponding subquery into the FROM clause. For example:
{ "select":{ "iatc":[ "id", "dest", "copy_status" ] }, "from": "iatc" }
There's nothing special-looking about this JSON, but json_query expands it as follows:
SELECT "iatc".id AS "id", "iatc".dest AS "dest", "iatc".copy_status AS "copy_status" FROM ( SELECT t.* FROM action.transit_copy t JOIN actor.org_unit AS s ON (t.source = s.id) JOIN actor.org_unit AS d ON (t.dest = d.id) WHERE s.parent_ou <> d.parent_ou ) AS "iatc" ;
The "iatc"
class is like a view, except that it's defined in the
IDL instead of the database. In this case it provides a way to do a join that would
otherwise be impossible through a JSON query, because it joins the same table in two
different ways (see the next subsection).
In a JOIN, as with other SQL constructs, there are some things that you can't do with a JSON query.
In particular, you can't specify a table alias, because the table alias is always the class name. As a result:
You can't join a table to itself. For example, you can't join actor.org_unit to itself in order to select the name of the parent for every org_unit.
You can't join to the same table in more than one way. For example, you can't join actor.org_unit to actor.org_address through four different foreign keys, to get four kinds of addresses in a single query.
The only workaround is to perform the join in a view, or in a subquery defined in the IDL as described in the previous subsection.
Some other things, while not impossible, require some ingenuity in the use of join filters.
For example: by default, json_query constructs a join condition using only a single pair of corresponding columns. As long as the database is designed accordingly, a single pair of columns will normally suffice. If you ever need to join on more than one pair of columns, you can use join filters for the extras.
Likewise, join conditions are normally equalities. In raw SQL it is possible (though rarely useful) to base a join on an inequality, or to use a function call in a join condition, or to omit any join condition in order to obtain a Cartesian product. If necessary, you can devise such unconventional joins by combining the normal join conditions with join filters.
For example, here's how to get a Cartesian product:
{ "select": { "aou":[ "id" ], "aout":[ "name" ] }, "from": { "aout": { "aou": { "filter": { "ou_type":{ "<>": { "+aout":"id" } } }, "filter_op":"or" } } } }
SELECT "aou".id AS "id", "aout".name AS "name" FROM actor.org_unit_type AS "aout" INNER JOIN actor.org_unit AS "aou" ON ( "aou".ou_type = "aout".id OR ("aou".ou_type <> ( "aout".id )) ) ;
Yes, it's ugly, but at least you're not likely to do it by accident.
In SQL, you can put a function call in the FROM clause. The function may return multiple columns and multiple rows. Within the query, the function behaves like a table.
A JSON query can also select from a function:
{ "from": [ "actor.org_unit_ancestors", 5 ] }
The data associated with "from"
is an array instead of a string
or an object. The first element in the array specifies the name of the function.
Subsequent elements, if any, supply the parameters of the function; they must be
literal values or nulls.
Here is the resulting query:
SELECT * FROM actor.org_unit_ancestors( '5' ) AS "actor.org_unit_ancestors" ;
In a JSON query this format is very limited, largely because the IDL knows nothing about the available functions. You can't join the function to a table or to another function. If you try to supply a SELECT list or a WHERE clause, json_query will ignore it. The generated query will always select every column, via a wild card asterisk, from every row.
In most cases you can encode an ORDER BY clause as either an array or an object. Let's take a simple example and try it both ways. First the array:
{ "select":{ "aou":[ "name" ] }, "from": "aou", "order_by": [ { "class":"aou", "field":"name" } ] }
Now the object:
{ "select":{ "aou":[ "name" ] }, "from": "aou", "order_by": { "aou":{ "name":{} } } }
The results are identical from either version:
SELECT "aou".name AS "name" FROM actor.org_unit AS "aou" ORDER BY "aou".name;
The array format is more verbose, but as we shall see, it is also more flexible. It can do anything the object format can do, plus some things that the object format can't do.
In the array format, each element of the array is an object defining one of the sort fields. Each such object must include at least two tags:
The "class"
tag provides the name of the class,
which must be either the core class or a joined class.
The "field"
tag provides the field name, corresponding
to one of the columns of the class.
If you want to sort by multiple fields, just include a separate object for each field.
If you want to sort a field in descending order, add a
"direction"
tag:
{ "select":{ "aou":[ "name" ] }, "from": "aou", "order_by": [ { "class":"aou", "field":"name", "direction":"desc" } ] }
SELECT "aou".name AS "name" FROM actor.org_unit AS "aou" ORDER BY "aou".name DESC;
The string tagged as "direction"
can be anything -- all that
matters is the first character. If the string starts with "D" or "d", the sort
will be descending. Otherwise it will be ascending. So
"diplodocus"
or "Dioscorides"
will work as
well as "desc"
, but "going down"
means that
the sort will go up.
You can also pass a column through some kind of transforming function, much as
you can in the SELECT and WHERE clauses, using the "transform"
tag. For example, for a case-insensitive sort, you could raise to upper case:
{ "select":{ "aou":[ "name" ] }, "from": "aou", "order_by": [ { "class":"aou", "field":"name", "transform":"upper" } ] }
SELECT "aou".name AS "name" FROM actor.org_unit AS "aou" ORDER BY upper("aou".name );
If you need additional parameters for the function, you can use the
"params"
tag to pass them:
{ "select":{ "aou":[ "name" ] }, "from": "aou", "order_by": [ { "class":"aou", "field":"name", "transform":"substr", "params":[ 1, 8 ] } ] }
The additional parameters appear as elements in an array. They may be numbers, strings, or nulls.
SELECT "aou".name AS "name" FROM actor.org_unit AS "aou" ORDER BY substr("aou".name,'1','8' );
As we have seen elsewhere, all literal values are passed as quoted strings, even if they are numbers.
If the function returns multiple columns, you can use the
"result_field"
tag to indicate which one you want (not shown).
When you encode the ORDER BY clause as an object, the keys of the object are class names. Each class must be either the core class or a joined class. The data for each class can be either an array or another layer of object. Here's an example with one of each:
{ "select":{ "aout":"id", "aou":[ "name" ] }, "from": { "aou":"aout" }, "order_by": { "aout":[ "id" ], "aou":{ "name":{ "direction":"desc" } } } }
For the "aout"
class, the associated array is simply a list
of field names (in this case, just one). Naturally, each field must reside in
the class with which it is associated.
However, a list of field names provides no way to specify the direction of
sorting, or a transforming function. You can add those details only if the
class name is paired with an object, as in the example for the
"aou"
class. The keys for such an object are field names, and
the associated tags define other details.
In this example, we use the "direction"
tag to specify that
the name field be sorted in descending order. This tag works the same way here as
described earlier. If the associated string starts with "D" or "d", the sort will
be descending; otherwise it will be ascending.
Here is the resulting SQL:
SELECT "aou".name AS "name" FROM actor.org_unit AS "aou" INNER JOIN actor.org_unit_type AS "aout" ON ( "aout".id = "aou".ou_type ) ORDER BY "aout".id, "aou".name DESC;
You can also use the "transform
", "params"
,
and "result_field"
tags to specify the use of a transforming
function, as described in the previous subsection. For example:
{ "select":{ "aou":[ "name", "id" ] }, "from": "aou", "order_by": { "aou":{ "name":{ "transform":"substr", "params":[ 1, 8 ] } } } }
SELECT "aou".name AS "name", "aou".id AS "id" FROM actor.org_unit AS "aou" ORDER BY substr("aou".name,'1','8' );
If you encode the ORDER BY clause as an object, you may encounter a couple of restrictions.
Because the key of such an object is the class name, all the fields from a given class must be grouped together. You can't sort by a column from one table, followed by a column from another table, followed by a column from the first table. If you need such a sort, you must encode the ORDER BY clause in the array format, which suffers from no such restrictions.
For similar reasons, with an ORDER BY clause encoded as an object, you can't reference the same column more than once. Although such a sort may seem perverse, there are situations where it can be useful, provided that the column is passed to a transforming function.
For example, you might want a case-insensitive sort, except that for any given letter you want lower case to sort first. For example, you want "diBona" to sort before "Dibona". Here's a way to do that, coding the ORDER BY clause as an array:
{ "select":{ "au":[ "family_name", "id" ] }, "from": "au", "order_by": [ { "class":"au", "field":"family_name", "transform":"upper" }, { "class":"au", "field":"family_name" } ] }
SELECT "au".family_name AS "family_name", "au".id AS "id" FROM actor.usr AS "au" ORDER BY upper("au".family_name ), "au".family_name;
Such a sort is not possible where the ORDER BY clause is coded as an object.
A JSON query has no separate construct to define a GROUP BY clause. Instead, the necessary information is distributed across the SELECT clause. However, the way it works is a bit backwards from what you might expect, so pay attention.
Here's an example:
{ "select": { "aou": [ { "column":"parent_ou" }, { "column":"name", "transform":"max", "aggregate":true } ] }, "from": "aou" }
The "transform"
tag is there just to give us an excuse to do a GROUP
BY. What's important to notice is the "aggregate"
tag.
Here's the resulting SQL:
SELECT "aou".parent_ou AS "parent_ou", max("aou".name ) AS "name" FROM actor.org_unit AS "aou" GROUP BY 1;
The GROUP BY clause references fields from the SELECT clause by numerical reference,
instead of by repeating them. Notice that the field it references, parent_ou, is the
one that doesn't carry the "aggregate"
tag in
the JSON.
Let's state that more generally. The GROUP BY clause includes only the fields that
do not carry the "aggregate"
tag (or that carry
it with a value of false).
However, that logic applies only when some field somewhere does
carry the "aggregate"
tag, with a value of true. If there is no
"aggregate"
tag, or it appears only with a value of false, then there
is no GROUP BY clause.
If you really want to include every field in the GROUP BY clause, don't use
"aggregate"
. Use the "distinct"
tag, as described
in the next section.
JSON queries don't generate DISTINCT clauses. However, they can generate GROUP BY clauses that include every item from the SELECT clause. The effect is the same as applying DISTINCT to the entire SELECT clause.
For example:
{ "select": { "aou": [ "parent_ou", "ou_type" ] }, "from":"aou", "distinct":"true" }
Note the "distinct"
entry at the top level of the
query object, with a value of "true".
SELECT "aou".parent_ou AS "parent_ou", "aou".ou_type AS "ou_type" FROM actor.org_unit AS "aou" GROUP BY 1, 2;
The generated GROUP BY clause references every column in the SELECT clause by number.
For a HAVING clause, add a "having"
entry at the top level
of the query object. For the associated data, you can use all the same syntax
that you can use for a WHERE clause.
Here's a simple example:
{ "select": { "aou": [ "parent_ou", { "column":"id", "transform":"count", "alias":"id_count", "aggregate":"true" } ] }, "from":"aou", "having": { "id": { ">" : { "transform":"count", "value":6 } } } }
We use the "aggregate" tag in the SELECT clause to give us a GROUP BY to go with the HAVING. Results:
SELECT "aou".parent_ou AS "parent_ou", count("aou".id ) AS "id_count" FROM actor.org_unit AS "aou" GROUP BY 1 HAVING count("aou".id ) > 6 ;
In raw SQL we could have referred to "count( 1 )". But since JSON queries cannot encode arbitrary expressions, we applied the count function to a column that cannot be null.
To add an LIMIT or OFFSET clause, add an entry to the top level of a query object. For example:
{ "select": { "aou": [ "id", "name" ] }, "from":"aou", "order_by": { "aou":[ "id" ] }, "offset": 7, "limit": 42 }
The data associated with "offset"
and "limit"
may be either a number or a string, but if it's a string, it should have a number
inside.
Result:
SELECT "aou".id AS "id", "aou".name AS "name" FROM actor.org_unit AS "aou" ORDER BY "aou".id LIMIT 42 OFFSET 7;