[open-ils-commits] [GIT] Evergreen ILS branch master updated. 391d7edf68bc7a67b69620ef74db36b7a79a9747

Evergreen Git git at git.evergreen-ils.org
Fri May 19 16:08:49 EDT 2017


This is an automated email from the git hooks/post-receive script. It was
generated because a ref change was pushed to the repository containing
the project "Evergreen ILS".

The branch, master has been updated
       via  391d7edf68bc7a67b69620ef74db36b7a79a9747 (commit)
       via  2d338c37ba685cde824f79432978f3a7524378be (commit)
       via  f87c94c4116dda099b85d3c67e34a7465ec524e5 (commit)
      from  7609099190455ce8662c8950e426c00552390a98 (commit)

Those revisions listed above that are new to this repository have
not appeared on any other notification email; so we list those
revisions in full, below.

- Log -----------------------------------------------------------------
commit 391d7edf68bc7a67b69620ef74db36b7a79a9747
Author: Galen Charlton <gmc at equinoxinitiative.org>
Date:   Tue May 2 10:57:23 2017 -0400

    LP#1678638: use new preferred extension for AsciiDoc files
    
    Signed-off-by: Galen Charlton <gmc at equinoxinitiative.org>
    Signed-off-by: Mike Rylander <mrylander at gmail.com>

diff --git a/docs/TechRef/qstore/qstore.txt b/docs/TechRef/qstore/qstore.adoc
similarity index 100%
rename from docs/TechRef/qstore/qstore.txt
rename to docs/TechRef/qstore/qstore.adoc
diff --git a/docs/TechRef/qstore/query_schema.txt b/docs/TechRef/qstore/query_schema.adoc
similarity index 100%
rename from docs/TechRef/qstore/query_schema.txt
rename to docs/TechRef/qstore/query_schema.adoc

commit 2d338c37ba685cde824f79432978f3a7524378be
Author: Galen Charlton <gmc at equinoxinitiative.org>
Date:   Sun Apr 2 15:15:56 2017 -0400

    LP#1678638: add text versions the qstore and query_schema docs
    
    qstore.txt includes some AsciiDoc markup, while query_schema.txt
    is just the results of passing query_schema.odt through unoconv
    and pandoc.
    
    Signed-off-by: Galen Charlton <gmc at equinoxinitiative.org>
    Signed-off-by: Mike Rylander <mrylander at gmail.com>

diff --git a/docs/TechRef/qstore/qstore.txt b/docs/TechRef/qstore/qstore.txt
new file mode 100644
index 0000000..db5c713
--- /dev/null
+++ b/docs/TechRef/qstore/qstore.txt
@@ -0,0 +1,390 @@
+Qstore
+======
+
+The qstore server (open-ils.qstore) executes database queries that have
+been previously defined, in an abstract form, within the database
+itself.  Such queries may be used for periodic reporting, ad hoc
+investigations, or automated updates.
+
+In some cases a query may be qualified by values to be supplied at
+execution time, called bind variables.  For example, a query may be
+limited to a particular org unit, or a short list of user ids.
+
+Before executing a query, the qstore client must open an application
+session with the qstore server by sending it a CONNECT message.  Then it
+must perform a series of steps to set up the query, execute it, and get
+the results.  Finally, the client may close the query explicitly with an
+additional method call.  Alternatively it may simply close the
+application session by sending a DISCONNECT message to the server.
+
+Here is a brief summary of the available methods.  Each will be
+discussed in greater detail in a later section:
+
+.  open-ils.qstore.prepare – load the query
+.  open-ils.qstore.sql – return the query as SQL
+.  open-ils.qstore.param_list – return a list of bind variables
+.  open-ils.qstore.bind_param – assign values to one or more bind
+variables
+.  open-ils.qstore.execute – execute the query and return the results
+.  open-ils.qstore.execute.atomic – an atomic version of the execute
+method
+.  open-ils.qstore.columns – return a list of column names for the
+results
+.  open-ils.qstore.finish – close a query, freeing any associated
+resources
+.  open-ils.qstore.messages – return any error message for a specified
+query
+
+The prepare method
+------------------
+Summary: Load a specified query.   Return a list of bind variables, and
+a token by which the query may be referenced in future method calls.
+
+Parameter: The id of a row in the query.stored_query table, identifying
+the stored query..
+
+Returns: A JSON object with two members:
+
+.  “token”: a text string to be used as a token for identifying the
+query in future method calls.  This string is designed to be unique, but
+otherwise has no very useful meaning.
+.  “bind_variables”: a (possibly empty) JSON object defining any bind
+variables required by the query.  See the discussion of the bind_param
+method.
+
+A client may juggle multiple queries in the same application session,
+using the corresponding tokens to identify the query to which each
+method call applies.
+
+The sql method
+--------------
+Summary: Return the query as an SQL string.
+
+Parameter: The token returned previously by the prepare method for the
+same query.
+
+Returns: A string containing the generated SQL corresponding to the
+stored query.  It will incorporate the specified values of any bind
+variables.  If no value has been assigned to a given bind variable, and
+there is no default value for it, then the generated SQL will include
+the name of the bind variable wherever it appears, preceded by a colon
+to distinguish it from a column name.  The user may review such a query
+but cannot execute it.
+
+The param_list method
+---------------------
+Summary: Returns information about the bind variables required by the
+query, if any.
+
+Parameter: The token returned previously by the prepare method for the
+same query.
+
+Returns: A JSON object keyed on the bind variable name.  The data
+associated with each name is another JSON object, with the following
+entries:
+
+.  “label”: the contents of query.bind_variable.label for this
+variable.  This is the identifier usually shown to the user for this
+variable.
+.  “type”: the contents of query.bind_variable.type for this variable.
+It is one of “string”, “number”, “string_list”, or “number_list”.
+.  “description”: the contents of query.bind_variable.description for
+this variable.
+.  “default_value”: the value that will be assigned to the variable if
+the user doesn't override it.
+.  “actual_value”: the value assigned by the user, overriding any
+default.
+
+Depending on the type, the default or actual value of a bind variable
+may be a string, a number, a JSON array of strings, or a JSON array of
+numbers.
+
+If a given variable has no default value, then there will be no entry
+for “default_value”.  On the other hand if the default value is a null,
+then there will be an entry for “default_value” whose associated data is
+a JSON null.  Likewise for “actual_value”.
+
+The bind_param method
+---------------------
+Summary: Assign a value to one or more bind variables.
+
+Parameter: This is the only qstore method that requires two parameters:
+
+.  The token returned previously by the prepare method for the same
+query.
+.  A (possibly empty) JSON object keyed on bind variable name.  The
+value associated with each bind variable name is the value to be
+assigned to the corresponding bind variable, overriding any default, and
+replacing any value previously assigned.
+
+The execute method
+------------------
+Summary: Execute the specified query, and return the results.
+
+Parameter: The token returned previously by the prepare method for the
+same query.
+
+Returns: Zero or more responses, each containing one row returned by the
+query.  Each row is represented by a JSON array of values.
+
+The execute.atomic method
+-------------------------
+Summary: Execute the specified query, and return the results.
+
+Parameter: The token returned previously by the prepare method for the
+same query.
+
+Returns: A JSON array containing zero or more entries.  Each entry
+represents a row as a JSON array of values.
+
+The columns method
+------------------
+Summary: Return the column names assigned by PostgreSQL to the result
+set of the query.
+
+Parameter: The token returned previously by the prepare method for the
+same query.
+
+Returns: An array of strings, each string being a column name.
+
+The finish method
+-----------------
+Summary: Close a query, freeing any resources associated with it, and
+rendering the token invalid for future method calls.
+
+Parameter: The token returned previously by the prepare method for the
+same query.
+
+Closing the application session will finish any unfinished queries for
+that session.
+
+The messages method
+-------------------
+Summary: Return any error messages associated with a query.
+
+Parameter: The token returned previously by the prepare method for the
+same query.
+
+Returns: A JSON array of strings, each string being an error message
+issued in connection with the specified query.  The messages appear in
+the order in which they were issued.  Typically the first message
+describes the error as it was first encountered, and subsequent messages
+describe the context in which the error occurred.
+
+The messages returned include all those issued for the specified query,
+including any issued for previous method calls.  Since currently there
+is no method for purging error messages, they just accumulate.
+
+In many cases (but not all), qstore writes similar messages to its log.
+ The messages method is based on the notion that most users shouldn't
+have to examine log files.  They may however need help in interpreting
+the error messages.
+
+Example
+
+The following srfsh session illustrates these methods.  After opening an
+application session, we prepare query 12:
+
+----
+srfsh# open open-ils.qstore
+
+Service open-ils.qstore opened
+
+srfsh# request open-ils.qstore open-ils.qstore.prepare 12
+
+Received Data: {
+  "token":"1_1279135310_6487",
+  "bind_variables":{
+    "ou":{
+      "label":"lib",
+      "type":"number",
+      "description":"org unit"
+    }
+  }
+}
+----
+
+The server concocts a unique token, "1_1279135310_6487”, that we will
+use henceforth to identify this query.  We could also prepare an
+unrelated query, or even the same query more than once, and qstore would
+assign each of them a different token and keep them all straight.  For
+this example, though, we'll stick to the one query.
+
+This query has one bind variable named “ou”, whose value needs to be
+numeric.  The label, “lib”, is a short name for handy reference
+(although in this case it's actually longer than the name used
+internally).  The description tells us that it identifies an org unit.
+ In a real example the description probably should be more verbose, so
+that user could see it in a tool tip (for example) and figure out what
+to do.
+
+In this case there is no default value, i.e. there is no entry for
+“default_value”.  That means we can't run the query yet – but we can
+still look at the SQL for it:
+
+----
+srfsh# request open-ils.qstore open-ils.qstore.sql "1_1279135310_6487"
+
+Received Data: "SELECT\n   \"aou\".id,\n   \"aou\".name,\n  
+\"aou\".shortname,\n  
+
+\"aou\".opac_visible,\n   \"aou\".parent_ou \nFROM\n   actor.org_unit AS
+\"aou\" \nWHERE\n   \"aou\".id = :ou;\n"
+----
+
+When we call the sql method, we pass it the token that the prepare
+method assigned earlier.  The server returns the generated SQL, trying
+to make it readable by inserting newlines and indentation.  In srfsh,
+though, the output is pretty ugly because all the newlines and quotation
+marks are escaped within a JSON string.  In this document, at least,
+it's line-wrapped so that it fits on the page.  In a proper GUI it
+should look much nicer.
+
+At the end of the SQL, the query refers to the bind variablee as “:ou”,
+the variable preceded by a colon.  The colon indicates that “ou” is a
+variable name rather than a column name.  It also makes the SQL invalid
+until we replace the variable with a real value.  Let's do that now, and
+then look at the SQL again:
+
+----
+srfsh# request open-ils.qstore open-ils.qstore.bind_param \
+"1_1279135310_6487" {"ou":3}
+
+srfsh# request open-ils.qstore open-ils.qstore.sql "1_1279135310_6487"
+
+Received Data: "SELECT\n   \"aou\".id,\n   \"aou\".name,\n  
+\"aou\".shortname,\n  
+\"aou\".opac_visible,\n   \"aou\".parent_ou \nFROM\n   actor.org_unit
+AS \"aou\" \nWHERE\n   \"aou\".id = 3;\n"
+----
+
+When we call the bind_param method we pass not only the token but also a
+JSON object assigning a value to one or more bind variables – just one
+in this case.  Now the generated SQL looks normal.
+
+We can also verify the substitution by calling the param_list method:
+
+----
+srfsh# request open-ils.qstore open-ils.qstore.param_list \
+"1_1279135310_6487"
+
+Received Data: {
+  "ou":{
+    "label":"lib",
+    "type":"number",
+    "description":"org unit",
+    "actual_value":3
+  }
+}
+----
+
+Now we see an “actual_value” of 3.  The SQL is ready to go.
+
+----
+srfsh# request open-ils.qstore open-ils.qstore.execute
+"1_1279135310_6487"
+
+Received Data: [
+  3,
+  "Example System 2",
+  "SYS2",
+  "t",
+  1
+]
+----
+
+This query returns only one row, so we get only one response.  If there
+were multiple rows, srfsh would display multiple lines of “Received
+Data.”  The one response is a JSON array of column values.
+
+Here's the atomic version of the same method call:
+
+----
+srfsh# request open-ils.qstore open-ils.qstore.execute.atomic \
+"1_1279135310_6487"
+
+Received Data: [
+  [
+    3,
+    "Example System 2",
+    "SYS2",
+    "t",
+    1
+  ]
+]
+----
+
+The difference isn't obvious because there's only one row, but notice
+the an extra layer of square brackets.  This result is an array of
+arrays of column values.  If there were multiple rows, they'd all be in
+the same array.
+
+This response does not identify the columns.  For that we must make
+another call:
+
+----
+srfsh# request open-ils.qstore open-ils.qstore.columns
+"1_1279135310_6487"
+
+Received Data: [
+  "id",
+  "name",
+  "shortname",
+  "opac_visible",
+  "parent_ou"
+]
+----
+
+The result is a JSON array of column names.  These are the same names
+that you would get if you ran the query in psql.  They may not be unique
+or even helpful.  Ideally the query should assign good column aliases,
+but if it doesn't, you have to take what you can get.
+
+Now let's make a mistake, just so that we can see an error message.
+ We're going to assign a value to a bind variable that doesn't exist,
+and then ask for any error messages:
+
+----
+srfsh# request open-ils.qstore open-ils.qstore.bind_param
+"1_1279135310_6487" {"goober":3}
+
+Received Exception:
+Name: osrfMethodException
+Status: Unable to apply values to bind variables
+Status: 400
+Received Exception:
+Name: osrfMethodException
+Status: An unknown server error occurred
+Status: 404
+
+srfsh# request open-ils.qstore open-ils.qstore.messages
+"1_1279135310_6487"
+
+Received Data: [
+  "Can't assign value to bind variable \"goober\": no such variable"
+]
+----
+
+The result is a JSON array of error messages as strings.  In this case
+there's only one message.  In other cases there may be a series of
+messages, the first one describing the error at the lowest level, and
+the rest providing additional context.
+
+Now that we're done with this query, we can shut it down:
+
+----
+srfsh# request open-ils.qstore open-ils.qstore.finish
+"1_1279135310_6487"
+
+Received no data from server
+
+srfsh# close open-ils.qstore
+
+Service "open-ils.qstore" closed
+
+srfsh# exit
+----
+
+The finish method closes the query and frees associated memory.  In this
+case we could have skipped it, because we immediately close the session
+anyway, thereby closing any outstanding queries.
diff --git a/docs/TechRef/qstore/query_schema.txt b/docs/TechRef/qstore/query_schema.txt
new file mode 100644
index 0000000..91d24b4
--- /dev/null
+++ b/docs/TechRef/qstore/query_schema.txt
@@ -0,0 +1,856 @@
+The Query Schema
+
+ 
+
+Introduction
+
+The query schema stores user-defined queries in an abstract form.  The
+qstore server reads the query tables, constructs the corresponding SQL,
+executes the query, and returns the result set.  This machinery supports
+three main kinds of uses:
+
+1.  Ad hoc queries
+2.  Repeated queries for reports or other kinds of extracts
+3.  Identifying rows that may be subject to automated updates
+
+Queries may be customized at run time through the use of bind variables.
+ For example, a query might  extract circulation statistics for a given
+branch.  It could include a bind variable as a placeholder for the org
+unit id, which the user would supply at run time.  A bind variable may
+represent a single value or a variable-length list of values.
+
+Although there are some limitations, the query tables can represent most
+of the queries that anyone is likely to want.  In particular they
+support many SQL constructs that json_query does not support.
+
+Warning: the machinery comprising qstore and the query tables is a text
+generator with little understanding of how databases work.  Depending on
+the contents of the query tables, it may generate invalid SQL.
+ PostgreSQL is the final arbiter.
+
+Summary of Tables
+
+The query schema includes the following tables, each of which is
+described in a later section:
+
+1.  stored_query – stores the topmost level of a query or subquery:
+SELECT, UNION, INTERSECT, or EXCEPT.  Other tables link to
+query.stored_query, directly or indirectly.
+2.  query_sequence – specifies the sequence of subordinate queries
+within a UNION, INTERSECT, or EXCEPT.
+3.  expression – each row represents an expression, often a
+subexpression of some larger expression.
+4.  from_relation – each row represents a FROM clause, or part of a FROM
+clause, identifying a table, view, subquery, or function from which the
+data are to be drawn.
+5.  select_item – each row specifies the location and content of an
+entry in a SELECT list.
+6.  order_by_item – each row specifies the location and content of an
+entry in an ORDER BY list.
+7.  function_sig – represents the names and return types of functions.
+8.  case_branch – represents branches in CASE expressions.
+9.  datatype – defines datatypes that may be used in CAST expressions.
+10. bind_variable – represents bind variables whose values may be
+supplied at execution time.
+
+Three other tables are currently unused, and will not be discussed in
+any detail here:
+
+1.  record_column – defines column sets for functions in a FROM clause.
+2.  function_param_def – defines the parameters of functions.
+3.  subfield – defines the components of composite types.
+
+The latter two may or may not turn out to be useful for the user
+interface code.
+
+Query.stored_query
+
+The stored_query table is the entry point into the query schema.  When
+you want qstore to construct a query, you give it the id of a row in
+query.stored_query.  Then qstore reads that row and all the rows
+connected to it, directly or indirectly, that collectively define the
+entire query.
+
+The columns are as follows:
+
+        id                        integer                primary key
+
+        type                        text                not null
+
+        use_all                        boolean        not null default
+false
+
+        use_distinct                boolean        not null default
+false
+
+        from_clause                integer                points to
+query.from_relation
+
+        where_clause                integer                points to
+query.expression
+
+        having_clause                integer                points to
+query.expression
+
+        limit_count                integer                points to
+query_expression
+
+        offset_count                integer                points to
+query_expression
+
+The id is normally assigned by a database sequence.
+
+The type column must be one of SELECT, UNION, INTERSECT, or UNION.  Most
+queries, of course, are SELECT statements.  Neither the query schema nor
+qstore supports queries in the form of VALUES lists.
+
+The use_all column indicates whether there will be an ALL clause on a
+UNION, INTERSECT, or UNION.  It is not meaningful for a SELECT.
+
+The use_distinct column indicates whether there will be a DISTINCT
+clause.  It is meaningful only for a SELECT.
+
+The from_clause column is meaningful only for a SELECT.  It points to
+the query.from_relation table to define the top-level or core relation
+in a FROM clause.
+
+.
+
+The where_clause and having_clause columns point to the query.expression
+table to define a WHERE and HAVING clause, respectively.  The
+expressions must evaluate to a boolean result, or else PostgreSQL will
+reject the query.  These columns are meaningful only for a SELECT.
+
+The limit_count and offset_count columns point to the query.expression
+table to define values for a LIMIT and OFFSET clause, respectively.  The
+expressions must evaluate to a numeric result, or else PostgreSQL will
+reject the query.  These columns are meaningful only for a SELECT.
+
+For GROUP BY clauses, see the section on the query.select_item table.
+
+Query.query_sequence
+
+The query.query_sequence table defines the sequence of subordinate
+queries within a UNION, INTERSECT, or EXCEPT query.  It provides a layer
+of indirection so that the same query can appear in multiple contexts.
+
+Its columns are as follows:
+
+        id                        integer                primary key
+
+        parent_query                integer                not null;
+points to query.stored_query
+
+        seq_no                        integer                not null
+
+        child_query                integer                not null
+
+The id is normally assigned by a database sequence.
+
+The parent_query column points to the UNION, INTERSECT, or EXCEPT query
+to which the subordinate query is subordinate.
+
+The seq_no column defines the placement of a given subordinate query
+within the parent.  No two subordinates of the same parent may have the
+same value for seq_no.
+
+The child_query column points to the subordinate query.  Typically it
+points to a SELECT, but it may point to a nested UNION, INTERSECT, or
+EXCEPT.
+
+Query.expression
+
+The query.expression table is easily the most complicated of the tables
+in the query schema.  There are many types of expressions, and they may
+be combined into structures of arbitrary complexity.  Expressions may
+appear in several different places within a query: in a SELECT list, in
+a WHERE, ORDER BY, or ON clause, or as subexpressions within larger
+expressions.
+
+Different kinds of expressions call for different combinations of
+ columns to be populated, as described in the Appendix.  However the
+following columns are relevant to all kinds of expressions:
+
+        id                        integer                primary key
+
+        type                        text                not null
+
+        parenthesize                boolean        not null; default
+false
+
+        parent_expr                integer                points to
+query.expression
+
+        seq_no                        integer                not null;
+default 1
+
+        negate                        boolean        not null; default
+false
+
+The id is normally assigned by a database sequence.
+
+The type column currently has sixteen possible values, which we will
+examine briefly below after introducing the other columns.
+
+If set to true, the parenthesize column tells qstore to enclose the
+entire expression in parentheses.  Usually qstore can figure out for
+itself when it needs to insert parentheses, but this column is available
+when you need it.
+
+The parent_expr column identifies the larger expression to which a
+subexpression belongs.  It isn't needed for every subexpression; only
+for those that may form series of two or more subexpressions, such as
+the parameters of a function call or the branches of a CASE expression.
+
+The seq_no column defines the sequence of subexpressions within the same
+larger expression.  No two expressions with the same parent expression
+may have the same sequence number.
+
+If true, the negate column tells qstore to negate the entire expression
+by inserting a NOT somewhere.  It is sensible to use it only when the
+expression evaluates to a boolean result.
+
+The usage of the remaining columns depends on the value of the type
+column, as detailed in the Appendix.  Here's a summary:
+
+The literal column contains a number (as text) or a string literal.  It
+may also contain “true” or “false” as a boolean literal.
+
+The column_name column contains the name of a column.  It may optionally
+be qualified by the table_alias column.
+
+The left_operand and right_operand columns point to subexpressions to
+appear with a designated operator.  The left_operand operator is also
+used to point to subexpressions in several other kinds of expressions,
+such as IN expressions and casts.
+
+The function_id column, pointing to a row in query.function_sig, is used
+to express a function call.
+
+The subquery column, pointing to a row in query.stored_query, refers to
+a subquery.
+
+The cast_type column, pointing to a row in query.datatype, is used to
+express a CAST expression.
+
+The bind_variable column, pointing to a row in query.bind_variable,
+identifies a placeholder whose value will be supplied by the user when
+he or she executes the query.
+
+Currently there are sixteen allowed values for the type column,
+signifying sixteen kinds of expressions:
+
+1.  xbet                BETWEEN expression
+2.  xbind                bind variable
+3.  xbool                boolean literal
+4.  xcase                CASE expression
+5.  xcast                CAST expression
+6.  xcol                column reference
+7.  xex                EXISTS expression
+8.  xfunc                function call
+9.  xin                IN expression
+10. xisnull                IS NULL expression
+11. xnull                null
+12. xnum                numeric literal
+13. xop                operator with one or two operands
+14. xser                series of subexpressions separated by operators
+or commas
+15. xstr                string literal
+16. xsubq                subquery
+
+For each expression type there is an updatable view containing only the
+columns that are relevant to that type.  The name of the view is the
+type prefaced by “expr_”; e.g.. query.exp_xbet.
+
+Neither the query schema nor qstore tries to determine the datatype of
+an expression.  For example, you can encode a nonsensical expression
+like 'W' + 3, or NOT CURRENT_DATE.  Though qstore will blithely generate
+the corresponding SQL, PostgreSQL will reject it.
+
+Query.from_relation
+
+A row in query.from_relation defines a table, view, function or subquery
+in the FROM clause, from which the SELECT will draw its data.
+
+Query.from_relation includes the following columns:
+
+        id                        integer                primary key
+
+        type                        text                not null
+
+        table_name                text
+
+        class_name                text
+
+        subquery                integer                points to
+query.stored_relation
+
+        function_call                integer                points to
+query.expression
+
+        table_alias                text
+
+        parent_relation        integer                points to
+query.from_relation
+
+        seq_no                        integer                not null;
+default 1
+
+        join_type                text
+
+        on_clause                integer                points to
+query.expression
+
+The id is normally assigned by a database sequence.
+
+The type must be one of RELATION (meaning table or view), SUBQUERY, or
+FUNCTION.  Depending on the type, different combinations of the other
+columns may be populated or not populated.
+
+The table_name column may be populated for a RELATION to specify the
+name of a table or view.
+
+The class_name column is another way to specify a table or view for a
+RELATION.  If table_name is null, qstore looks up the class_name in the
+IDL in order to get the name of the table or view – or in some cases the
+body of a subquery defined in the IDL.
+
+If the type is SUBQUERY, then the subquery column must point to a row in
+query.stored_query.  Otherwise this column has no meaning.
+
+If the type is FUNCTION, then the function_call column must point to a
+row in query.expression, and that row must represent a function call
+expression.  Otherwise this column has no meaning.
+
+The table_alias column defines an alias to be used for the table, view,
+subquery, or function.  If table_alias is null, but class_name is
+populated, then qstore will use the class_name as an alias.
+
+The parent_relation column is used for joins.  If a relation is joined
+to the top-level relation (the one to which the query.stored_query table
+points), then parent_relation points to the top level.  Otherwise it
+points to a relation that points to the top level, directly or
+indirectly.
+
+The seq_no field defines the sequence of relations with the same parent.
+ No two rows with the same value of parent_relation may have the same
+seq_no.
+
+If parent_relation is populated, then the join_type column must be
+populated with one of INNER, LEFT, RIGHT or FULL to indicate the type of
+join.
+
+The on_clause column is meaningful only if parent_relation is populated.
+ It points to a row in query.expression representing the join condition,
+which must evaluate to a boolean result.
+
+Query.select_item
+
+Each row in query.select_item represents an item in a SELECT list.  The
+columns are as follows:
+
+        id                        integer                primary key
+
+        stored_query                integer                not null
+
+        seq_no                        integer                not null
+
+        expression                integer                not null
+
+        column_alias                text
+
+        grouped_by                boolean        not null; default false
+
+The id is normally assigned by a database sequence.
+
+The stored_query column points to the query to whose SELECT list the
+item belongs.  The query must be a SELECT.
+
+The seq_no column defines the sequence of items within the SELECT list.
+ No two items within the same SELECT list may have the same value of
+seq_no.
+
+The expression column points to a row of any type in query.expression.
+
+The column_alias column specifies a column alias to be supplied in an AS
+clause.  The generated SQL will enclose the column alias in double
+quotes.
+
+The grouped_by column stipulates that the SELECT item be referenced in a
+GROUP BY clause.  The generated SQL references the item by its ordinal
+position within the list, which may or may not be the same as the value
+of the seq_no column.  It's up to you to ensure that the resulting GROUP
+BY clause is valid; i.e. if any item is in a GROUP BY clause, then every
+other item that isn't an aggregate function must also be included in the
+GROUP BY clause.
+
+In SQL it is possible, though seldom useful, to include something in the
+GROUP BY clause that is not included in the SELECT list.  However the
+query schema provides no way to encode such a query directly.  The
+workaround, should you ever need it, is to do the GROUP BY in a subquery
+that includes everything it needs in the SELECT list, while the outer
+query picks out only the items you want to keep.
+
+Query.order_by_item
+
+Each row in query.order_by_item specifies an expression in an ORDER BY
+list.  Its columns are as follows:
+
+        id                        integer                primary key
+
+        stored_query                integer                not null;
+points to query.stored_query
+
+        seq_no                        integer                not null
+
+        expression                integer                not null;
+points to query.expression
+
+The id is normally assigned by a database sequence.
+
+The stored_query column identifies the query to which the ORDER BY
+clause applies.  This query must be a SELECT.
+
+The seq_no column defines the sequence of items in the ORDER BY clause.
+ No two ORDER BY items for the same query may have the same value in
+seq_no.
+
+The expression column, pointing to a row in query.expression, identifies
+an expression by which the query results will be sorted.
+
+The generated ORDER BY clause includes the specified expressions bodily,
+rather than by referring to items by their ordinal position in the
+SELECT clause.  As a result, you can include expressions that aren't in
+the SELECT clause at all.
+
+As a further result, the ORDER by clause becomes ugly and bulky if the
+expressions are large and complicated.  If you really want to reference
+expressions in the SELECT list by number, use the corresponding numeric
+constants as your ORDER BY expressions.
+
+It may seem confusing that ORDER BY doesn't work the same way as GROUP
+BY (see the discussion of the latter in the section on the
+query.select_item table).  In SQL, either clause can reference an
+expression outside of the SELECT clause, but the query schema allows
+such a reference only for ORDER BY.  For GROUP BY you can get the same
+effect only through an awkward workaround.
+
+These design choices reflect a sense that having to use a workaround, in
+order to list an expression not in the SELECT list, is more likely to be
+a problem for ORDER BY than for GROUP BY.
+
+Query.function_sig.
+
+The query.function_sig table stores information about function
+signatures:
+
+        id                        integer                primary key
+
+        function_name        text                not null
+
+        return_type                integer                points to
+query.datatype
+
+        is_aggregate                boolean        not null; default
+false
+
+The id is normally assigned by a database sequence.
+
+The function_name column stores the name of the function.
+
+The return_type column, pointing to a row in query.datatype, indicates
+the return type of the function.
+
+The is_aggregate column, if true, indicates that the function is an
+aggregate function such as max() or sum().  Aggregate functions
+typically don't have specific return types, because the effective return
+type depends on the type of the argument.
+
+Qstore pays attention only to the id and function_name columns; the
+other two columns may be useful to the user interface.  Likewise qstore
+pays no attention to the query.function_param_def table, which defines
+the datatypes of the function parameters.
+
+Query.case_branch
+
+The query schema represents a CASE expression as a row in
+query.expression, with the type column set to “xcase”.  For each branch
+of the CASE expression there is a row in query.case_branch.  Its columns
+are as follows:
+
+        id                        integer                primary key
+
+        parent_expr                integer                not null;
+points to query.expression
+
+        seq_no                        integer                not null
+
+        condition                integer                points to
+query.expression
+
+        result                        integer                not null;
+points to query.expression
+
+The id is normally assigned by a database sequence.
+
+The parent_expr column points to a row in query.expression representing
+the entire CASE expression to which the branch belongs.
+
+The seq_no column defines the sequence of branches within the CASE
+expression.  No two branches within the same CASE expression may have
+the same value of seq_no.
+
+The condition column, pointing to a row in query.expression, represents
+a possible value of the expression being tested.  In the generated SQL,
+the corresponding expression will follow the WHEN keyword.
+
+The result column, pointing to a row in query.expression, represents the
+value to which the CASE expression evaluates if the branch is followed.
+ In the generated SQL, the corresponding expression will follow the THEN
+or ELSE keyword.
+
+If the condition column is null, then the branch is the ELSE branch.
+ There may be no more than one such branch in a given CASE statement,
+and it must be the last branch.
+
+Query.datatype
+
+The query schema represents a CAST expression with a row in
+query.expression, where the type column is set to “xcast”.  To identify
+the datatype to which the operand is being cast, the query.row.datatype
+column points to a row in query.datatype, which has the following
+columns:
+
+        id                        integer                primary key
+
+        datatype_name        text                not null
+
+        is_numeric                boolean        not null; default false
+
+        is_composite                boolean        not null; default
+false
+
+The id is normally assigned by a database sequence.
+
+The datatype_name column, of course, the name of the datatype.
+
+The is_numeric column, if true, indicates that the the type is numeric.
+
+The is_composite column, if true, indicates that the datatype is
+composed of two or more subfields, which may themselves be defined in
+the query.subfield table.
+
+Qstore pays attention only to the datatype_name and id columns.  The
+other two columns, and the query.subfield table, may be useful for the
+user interface.
+
+Query.bind_variable
+
+The query.bind_variable table defines variables that may appear within
+the query.  Before executing the query, the user must supply a value for
+each such variable, or accept the default value if one is defined.  The
+columns are as follows:
+
+        name                        text                primary key
+
+        type                        text                not null
+
+        description                text                not null
+
+        default_value                text
+
+        laqbel                        text                not null
+
+The name column is the primary key, and contains the name of the
+variable
+
+Depending on what kind of value the variable may hold, the type column
+contains one of “string”, “number”, “string_list”, or “number_list”..
+ The first two denote individual scalar values, and the latter two
+denote comma-separated lists of scalars.  A null value may be encoded by
+the JSON keyword “null”.
+
+The description column describes the variable so that the user can know
+what it's for.
+
+The default_value column, if populated, contains the value that will be
+used if the user does not specify some other value.  This value must be
+encoded as JSON; a list type must be encoded as a JSON array.
+
+The label column is the identifier that will normally be shown to the
+user.  It should be reasonably short and descriptive, but it need not be
+unique.  The name provides uniqueness, and since it will mainly be used
+internally, need not be as human-friendly as the label.
+
+If qstore is asked to generate SQL for query with a bind variable that
+has not been assigned a value, it will include the bind variable name in
+the output SQL, preceded by a colon to mark it as a bind variable.  Such
+a query cannot be executed, but it can be displayed to the user for
+review.
+
+Appendix: Expressions
+
+A row in the query.expression table may represent any of several kinds
+of expressions, as denoted by the contents of the type column.  As noted
+earlier, some of the columns in query.expression apply to all kinds of
+expressions.  The rest apply only to some kinds of expressions and not
+to others, in various combinations.
+
+This appendix discusses each expression type in turn, and how to
+represent it.
+
+xbet: BETWEEN
+
+An “xbet” expression involves three subexpressions:
+
+        A BETWEEN B AND C
+
+The left_operand column points to subexpression A.  There must be
+exactly two other rows representing subexpressions B and C, whose
+parent_expr columns point to the “xbet” row.
+
+The values of their seq_no columns determine which one comes first.
+
+If the negate column is set to true, then the result is a NOT BETWEEN
+expression.
+
+xbind: Bind Variable
+
+An “xbind” expression refers to a bind variable, i.e. a value or series
+of values that the user must supply before executing the query.  In
+query.expression, the bind_variable column points to a row in the
+ query.bind_variable table, which defines a name and a label for the
+bind variable, and possibly a default value.
+
+xbool: BOOLEAN
+
+An “xbool” expression is a boolean literal.  The literal column contains
+“true” or “false” in any combination of upper, lower, or mixed case.
+
+xcase: CASE
+
+An “xcase” expression represents a CASE structure, as in the following
+example:
+
+        CASE A
+
+                WHEN B THEN C
+
+                WHEN D THEN E
+
+                ELSE F
+
+        END
+
+The left_operand column contains A, the value being tested.  Each branch
+of the CASE is represented by a row in query.case_branch, where the
+condition column points to subexpressions B and D, and the result column
+points to subexpressions C, E, and F.  For the ELSE branch, the
+condition column is null.
+
+In the query.case_branch table, the seq_no column defines the order in
+which the branches appear.  If there is an ELSE branch, it must come
+last.
+
+xcast: CAST
+
+An “xcast” expression casts a subexpression to a datatype:
+
+        CAST (A AS B)
+
+The left_operand column points to A, the expression being cast.  The
+cast_type column points to a row in query.datatype that defines the
+datatype B.
+
+xcol: Column Reference
+
+An “xcol” expression refers to the contents of a column, optionally
+qualified by an alias for a table, view, or other relation:
+
+        “A”.B
+
+The column_name column contains the name of the column B.  The
+table_alias column, if not null, contains the alias A.  Since qstore
+always encloses the alias in quotation marks, there is no way to qualify
+a column name by a raw table name.
+
+xex: EXISTS
+
+An “xex” expression is an EXISTS clause with a subquery.  The subquery
+column points to a row in query.stored_query.
+
+If the negate column is set to true, the result is a NOT EXISTS
+expression.
+
+xfunc: Function Call
+
+An “xfunc” expression is a function call:
+
+        A( B, C, D ... )
+
+The function_id column points to a row in query.function_sig that
+defines the function name A and other aspects of the function
+signature..  Each parameter B, C, etc. is represented by a row in
+query.expression, where parent_expr points to the “xfunc” row.  The
+seq_no columns for the various parameters define their positions within
+the parameter list.
+
+If a function returns a composite type, it is possible to specify a
+subfield of the return value:
+
+        (A( B, C, D ... )).”E”
+
+In such a case, the column_name column contains the subfield name E.
+
+Some built-in SQL functions don't follow the usual syntax of
+parameter-passing.  For example, the following function not only don't
+accept any parameters, they don't even accept empty parentheses:
+
+        current_date
+
+        current_time
+
+        current_timestamp
+
+        localtime
+
+        localtimestamp
+
+Qstore treats these functions as special exceptions in order to avoid
+adding empty parentheses.
+
+The extract function requires an extra keyword within the parameter
+list:
+
+        extract( A FROM B )
+
+...where A is one of a short list of unquoted strings.  Qstore treats
+calls to extract() as a special exception: pass A as if it were a string
+literal, and qstore will build the call with a FROM and an unquoted A.
+
+Qstore does not currently support other irregular functions.
+
+xin: IN
+
+An “xin” expression may take either of two forms.  One form involves a
+subquery:
+
+        A IN ( subquery )
+
+The left_operand column contains a pointer to another row in
+query.expression, representing the value A to be tested.  The subquery
+column points to a row in query.stored_query, defining the subquery.
+
+The other form involves a list of values:
+
+        A IN (B, C, D ... )
+
+Again, the left_operand indicates the value to be tested.  Each value in
+the list is represented by a row in query.expression whose parent_expr
+column points to the “xin” row.  The seq_no columns of the subexpression
+rows define the order of their appearance.
+
+If the negate column is set to true, then the result is a NOT IN
+expression.
+
+xisnull: IS NULL
+
+An “xisnull” expression tests whether a given value is null:
+
+        A IS NULL
+
+The left_operand column points to row in query.expression representing
+the value to be tested.
+
+If the negate column is set to true, then the result is an IS NOT NULL
+expression.
+
+xnull: NULL
+
+An “xnull” expression represents a null value (and not a test for
+nullity).
+
+xnum: NUMBER
+
+An “xnum” expression represents a numeric literal.  The literal column
+contains the value as a string.  This string may contain leading and/or
+trailing white space, but otherwise must be numeric – possibly including
+a leading minus sign, a decimal point, and/or scientific notation.
+ Currently this validation applies JSON's rules, which may differ in
+some respects from SQL's rules.
+
+xop: Operator
+
+An “xop” expression consists of an operator and one or two operands:
+
+        A operator B
+
+        C operator
+
+        operator D
+
+The operator column contains the operator as a string.  This string may
+contain any of the usual SQL operators.  It may also contain a
+non-standard custom operator, as long as it does not include white space
+or a semicolon.  (This support for custom operators was inherited from
+json_query, where it makes sense.  In qstore this support is unnecessary
+and may be withdrawn in future releases.)
+
+As special exceptions, the phrases "similar to", "is distinct from", and
+"is not distinct from" may be used as binary operators, in any
+combination of upper, lower, and mixed case, provided that they contain
+no additional white space.
+
+For a binary operator, then the left_operand column points to another
+row in query.expression that represents the operand to the left of the
+operator.  Likewise the right_operand column identifies the expression
+on the right.
+
+A few operators take only one operand.  Accordingly only the
+left_operand or right_operand column should be populated, depending on
+whether the operand should appear to the left of the operator (such as
+the factorial operator “!”) or to its right (such as the unary minus
+operator).
+
+xser: Series
+
+An “xser” expression is a series of expressions separated by a specified
+operator, or (if no operator is specifed) by commas:
+
+        A operator B operator C operator ... D
+
+        A, B, C, ... D
+
+ Typically the operator will be AND or OR, combining multiple conditions
+in the WHERE clause.  It is also possible to use, for example, an
+arithmetic operator like “+”, or the concatenation operator “||”.
+
+If the operator column is null, then qstore separates the expressions
+with commas.  By enclosing such a series in parentheses you can
+construct a tuple.
+
+Each subexpression in the series is represented by another row in
+query.expression, whose parent_expr column points to the “xser” row.
+ The seq_no columns of the subexpressions define the order of their
+appearance within the series.
+
+The same operator is used for the entire series.  If you need to combine
+different operators in the same expression, as in A + B – C, then you
+must nest multiple “xser” and “xop” expressions as needed.
+
+Strictly speaking, the “xser” type isn't necessary.  You can create all
+the same expressions by nesting “xop” expressions, although it may be
+rather cumbersome to do so.  The “xser” type is merely a convenience,
+making it easier to express certain common constructs.
+
+xstr: Character String
+
+An “xstr” expression consists of a character string, which must be
+stored in the literal column.  If the string contains any special
+characters such as quotation marks or backslashes, qstore will escape
+them as needed when it constructs the query.
+
+xsubq: Subquery
+
+An “xsubq” expression represents a subquery.  The subquery column points
+to a row in query.stored_query to identify the query.

commit f87c94c4116dda099b85d3c67e34a7465ec524e5
Author: Galen Charlton <gmc at equinoxinitiative.org>
Date:   Sun Apr 2 14:59:00 2017 -0400

    LP#1678638: technical documentation for qstore
    
    Technical documentation and sample stored queries for
    the open-ils.qstore service, written by Scott McKellar
    and copyright 2010 by the Equinox Open Library Initiative.
    
    Signed-off-by: Galen Charlton <gmc at equinoxinitiative.org>
    Signed-off-by: Mike Rylander <mrylander at gmail.com>

diff --git a/docs/TechRef/qstore/README b/docs/TechRef/qstore/README
new file mode 100644
index 0000000..a0209b1
--- /dev/null
+++ b/docs/TechRef/qstore/README
@@ -0,0 +1,60 @@
+This archive includes documentation of the query schema and the
+qstore server, along with some examples of stored queries.
+
+The query schema stores database queries in an abstract form
+within the database itself.
+
+The qstore server loads queries from the query schema, constructs
+the corresponding SQL, and executes the queries.
+
+Table of contents:
+
+qstore.odt
+
+	Documentation of the qstore methods.
+
+query_dump.sh
+
+	A shell script used to generate query_dump.sql, using the
+	pg_dump utility.  I include this script mostly for my own
+	convenience in case I want to update this archive, but you may
+	find it useful to know exactly where the sql script came from.
+	(Note: after generating the sql script I manually edited it to
+	remove the loading of the datatype table.)
+
+query_dump.sql
+
+	An sql script to install a collection of examples.  The script
+	assumes that the query schema exists but has no data in it,
+	except for the datatypes in query.datatype as installed by
+	the installation script.
+
+query_schema.odt
+
+	Documentation of the query schema.
+
+README
+
+	You're looking at it.
+
+stored_queries.txt
+
+	SQL queries generated from the queries loaded by query_dump.sql.
+
+test_qstore.txt
+
+	Documentation of the test_qstore utility.  The same documentation
+	appears in a comment block at the top of test_qstore.c.
+
+The sql script loads 25 example queries, with query ids in the range 1-25.  
+These are the queries I used to develop and test qstore.  I used
+the test_qstore utility to generate each query, and then pasted the
+output into stored_queries.txt.
+
+The queries themselves are not particularly useful, and often don't
+even make much sense from an application standpoint.  They are just
+exercises in the generation of syntax.  In any case they all run
+successfully within psql (except for query # 12, which features
+an unsubstituted bind variable).
+
+Scott McKellar
diff --git a/docs/TechRef/qstore/qstore.odt b/docs/TechRef/qstore/qstore.odt
new file mode 100644
index 0000000..2f416e8
Binary files /dev/null and b/docs/TechRef/qstore/qstore.odt differ
diff --git a/docs/TechRef/qstore/query_dump.sh b/docs/TechRef/qstore/query_dump.sh
new file mode 100755
index 0000000..f3e9676
--- /dev/null
+++ b/docs/TechRef/qstore/query_dump.sh
@@ -0,0 +1,9 @@
+pg_dump -n query \
+	--file=query_dump.sql \
+	--data-only \
+	--schema=query \
+	--disable-triggers \
+	--host=localhost \
+	--username=evergreen \
+	--password \
+	evergreen
diff --git a/docs/TechRef/qstore/query_dump.sql b/docs/TechRef/qstore/query_dump.sql
new file mode 100644
index 0000000..4a7c062
--- /dev/null
+++ b/docs/TechRef/qstore/query_dump.sql
@@ -0,0 +1,393 @@
+--
+-- PostgreSQL database dump
+--
+
+SET client_encoding = 'UTF8';
+SET standard_conforming_strings = off;
+SET check_function_bodies = false;
+SET client_min_messages = warning;
+SET escape_string_warning = off;
+
+SET search_path = query, pg_catalog;
+
+--
+-- Name: case_branch_id_seq; Type: SEQUENCE SET; Schema: query; Owner: evergreen
+--
+
+SELECT pg_catalog.setval('case_branch_id_seq', 3, true);
+
+
+--
+-- Name: expression_id_seq; Type: SEQUENCE SET; Schema: query; Owner: evergreen
+--
+
+SELECT pg_catalog.setval('expression_id_seq', 60, true);
+
+
+--
+-- Name: from_relation_id_seq; Type: SEQUENCE SET; Schema: query; Owner: evergreen
+--
+
+SELECT pg_catalog.setval('from_relation_id_seq', 10, true);
+
+
+--
+-- Name: function_param_def_id_seq; Type: SEQUENCE SET; Schema: query; Owner: evergreen
+--
+
+SELECT pg_catalog.setval('function_param_def_id_seq', 1, false);
+
+
+--
+-- Name: function_sig_id_seq; Type: SEQUENCE SET; Schema: query; Owner: evergreen
+--
+
+SELECT pg_catalog.setval('function_sig_id_seq', 6, true);
+
+
+--
+-- Name: order_by_item_id_seq; Type: SEQUENCE SET; Schema: query; Owner: evergreen
+--
+
+SELECT pg_catalog.setval('order_by_item_id_seq', 4, true);
+
+
+--
+-- Name: query_sequence_id_seq; Type: SEQUENCE SET; Schema: query; Owner: evergreen
+--
+
+SELECT pg_catalog.setval('query_sequence_id_seq', 4, true);
+
+
+--
+-- Name: record_column_id_seq; Type: SEQUENCE SET; Schema: query; Owner: evergreen
+--
+
+SELECT pg_catalog.setval('record_column_id_seq', 1, false);
+
+
+--
+-- Name: select_item_id_seq; Type: SEQUENCE SET; Schema: query; Owner: evergreen
+--
+
+SELECT pg_catalog.setval('select_item_id_seq', 47, true);
+
+
+--
+-- Name: stored_query_id_seq; Type: SEQUENCE SET; Schema: query; Owner: evergreen
+--
+
+SELECT pg_catalog.setval('stored_query_id_seq', 25, true);
+
+
+--
+-- Name: subfield_id_seq; Type: SEQUENCE SET; Schema: query; Owner: evergreen
+--
+
+SELECT pg_catalog.setval('subfield_id_seq', 1, false);
+
+
+--
+-- Data for Name: bind_variable; Type: TABLE DATA; Schema: query; Owner: evergreen
+--
+
+ALTER TABLE bind_variable DISABLE TRIGGER ALL;
+
+COPY bind_variable (name, type, description, default_value, label) FROM stdin;
+shortname	string	org unit shortname	"BR3"	lib shortname
+O'Leary	string	Ireland's kind of name	"O'Bryan"	nom d'Eire
+ou	number	org unit	\N	lib
+\.
+
+
+ALTER TABLE bind_variable ENABLE TRIGGER ALL;
+
+--
+-- Data for Name: case_branch; Type: TABLE DATA; Schema: query; Owner: evergreen
+--
+
+ALTER TABLE case_branch DISABLE TRIGGER ALL;
+
+COPY case_branch (id, parent_expr, seq_no, condition, result) FROM stdin;
+2	53	2	54	56
+3	53	3	\N	57
+1	53	1	58	55
+\.
+
+
+ALTER TABLE case_branch ENABLE TRIGGER ALL;
+
+--
+-- Data for Name: expression; Type: TABLE DATA; Schema: query; Owner: evergreen
+--
+
+ALTER TABLE expression DISABLE TRIGGER ALL;
+
+COPY expression (id, type, parenthesize, parent_expr, seq_no, literal, table_alias, column_name, left_operand, operator, right_operand, function_id, subquery, cast_type, negate, bind_variable) FROM stdin;
+1	xbool	f	\N	1	TRUE	\N	\N	\N	\N	\N	\N	\N	\N	f	\N
+2	xcol	f	\N	1	\N	aou	id	\N	\N	\N	\N	\N	\N	f	\N
+3	xcol	f	\N	1	\N	aou	name	\N	\N	\N	\N	\N	\N	f	\N
+4	xcol	f	\N	1	\N	aou	shortname	\N	\N	\N	\N	\N	\N	f	\N
+5	xcol	f	\N	1	\N	aou	parent_ou	\N	\N	\N	\N	\N	\N	f	\N
+6	xnum	f	\N	1	3	\N	\N	\N	\N	\N	\N	\N	\N	f	\N
+7	xop	f	\N	1	\N	\N	\N	5	>	6	\N	\N	\N	f	\N
+8	xop	f	\N	1	\N	\N	\N	2	=	6	\N	\N	\N	f	\N
+9	xsubq	f	\N	1	\N	\N	\N	\N	\N	\N	\N	3	\N	f	\N
+10	xcol	f	\N	1	\N	aout	id	\N	\N	\N	\N	\N	\N	f	\N
+11	xin	f	\N	1	\N	\N	\N	10	\N	\N	\N	3	\N	f	\N
+12	xcol	f	\N	1	\N	aou	ou_type	\N	\N	\N	\N	\N	\N	f	\N
+13	xcol	f	\N	1	\N	au	id	\N	\N	\N	\N	\N	\N	f	\N
+14	xop	f	\N	1	\N	\N	\N	13	=	12	\N	\N	\N	f	\N
+15	xex	f	\N	1	\N	\N	\N	\N	\N	\N	\N	3	\N	f	\N
+16	xcol	f	\N	1	\N	aou	\N	\N	\N	\N	\N	\N	\N	f	\N
+17	xbind	f	\N	1	\N	\N	\N	\N	\N	\N	\N	\N	\N	f	ou
+18	xop	f	\N	1	\N	\N	\N	2	=	17	\N	\N	\N	f	\N
+19	xcol	f	\N	1	\N	aou	opac_visible	\N	\N	\N	\N	\N	\N	f	\N
+20	xbind	f	\N	1	\N	\N	\N	\N	\N	\N	\N	\N	\N	f	shortname
+21	xop	f	\N	1	\N	\N	\N	4	=	20	\N	\N	\N	f	\N
+23	xcol	f	\N	1	\N	aou	email	\N	\N	\N	\N	\N	\N	f	\N
+24	xcol	f	\N	1	\N	aou	holds_address	\N	\N	\N	\N	\N	\N	f	\N
+27	xser	f	\N	1	\N	\N	\N	\N	OR	\N	\N	\N	\N	f	\N
+22	xisnull	f	27	1	\N	\N	\N	5	\N	\N	\N	\N	\N	f	\N
+25	xisnull	f	27	2	\N	\N	\N	23	\N	\N	\N	\N	\N	f	\N
+26	xisnull	f	27	3	\N	\N	\N	24	\N	\N	\N	\N	\N	f	\N
+32	xin	f	\N	1	\N	\N	\N	5	\N	\N	\N	\N	\N	f	\N
+29	xnum	f	32	1	1	\N	\N	\N	\N	\N	\N	\N	\N	f	\N
+30	xnum	f	32	2	3	\N	\N	\N	\N	\N	\N	\N	\N	f	\N
+31	xnum	f	32	3	6	\N	\N	\N	\N	\N	\N	\N	\N	f	\N
+33	xfunc	f	\N	1	\N	\N	\N	\N	\N	\N	1	\N	\N	f	\N
+34	xcol	f	33	1	\N	aou	name	\N	\N	\N	\N	\N	\N	f	\N
+35	xop	f	\N	1	\N	\N	\N	2	=	6	\N	\N	\N	f	\N
+36	xfunc	f	\N	1	\N	\N	name	\N	\N	\N	2	\N	\N	f	\N
+37	xcol	f	36	1	\N	aou	id	\N	\N	\N	\N	\N	\N	f	\N
+38	xbet	f	\N	1	\N	\N	\N	5	\N	\N	\N	\N	\N	f	\N
+39	xnum	f	38	1	1	\N	\N	\N	\N	\N	\N	\N	\N	f	\N
+40	xnum	f	38	2	4	\N	\N	\N	\N	\N	\N	\N	\N	f	\N
+41	xfunc	f	\N	1	\N	\N	\N	\N	\N	\N	3	\N	\N	f	\N
+42	xstr	f	41	1	DOW	\N	\N	\N	\N	\N	\N	\N	\N	f	\N
+43	xcol	f	41	2	\N	au	create_date	\N	\N	\N	\N	\N	\N	f	\N
+44	xfunc	f	\N	1	\N	\N	\N	\N	\N	\N	4	\N	\N	f	\N
+45	xnum	f	44	1	1	\N	\N	\N	\N	\N	\N	\N	\N	f	\N
+46	xfunc	f	\N	1	\N	\N	\N	\N	\N	\N	1	\N	\N	f	\N
+47	xstr	f	46	1	goober	\N	\N	\N	\N	\N	\N	\N	\N	f	\N
+48	xcol	f	\N	1	\N	\N	\N	\N	\N	\N	\N	\N	\N	f	\N
+49	xfunc	f	\N	1	\N	\N	\N	\N	\N	\N	5	\N	\N	f	\N
+50	xfunc	f	\N	1	\N	\N	\N	\N	\N	\N	6	\N	\N	f	\N
+51	xstr	f	50	1	both	\N	\N	\N	\N	\N	\N	\N	\N	f	\N
+52	xcol	f	50	2	\N	au	usrname	\N	\N	\N	\N	\N	\N	f	\N
+54	xnum	f	\N	1	2	\N	\N	\N	\N	\N	\N	\N	\N	f	\N
+55	xstr	f	\N	1	First	\N	\N	\N	\N	\N	\N	\N	\N	f	\N
+56	xstr	f	\N	1	Second	\N	\N	\N	\N	\N	\N	\N	\N	f	\N
+57	xstr	f	\N	1	Other	\N	\N	\N	\N	\N	\N	\N	\N	f	\N
+53	xcase	f	\N	1	\N	\N	\N	2	\N	\N	\N	\N	\N	f	\N
+58	xnum	f	\N	1	1	\N	\N	\N	\N	\N	\N	\N	\N	f	\N
+59	xcast	f	\N	1	\N	\N	\N	2	\N	\N	\N	\N	13	f	\N
+60	xnum	f	\N	1	100	\N	\N	\N	\N	\N	\N	\N	\N	f	\N
+\.
+
+
+ALTER TABLE expression ENABLE TRIGGER ALL;
+
+--
+-- Data for Name: from_relation; Type: TABLE DATA; Schema: query; Owner: evergreen
+--
+
+ALTER TABLE from_relation DISABLE TRIGGER ALL;
+
+COPY from_relation (id, type, table_name, class_name, subquery, function_call, table_alias, parent_relation, seq_no, join_type, on_clause) FROM stdin;
+1	RELATION	actor.org_unit	aou	\N	\N	aou	\N	1	\N	\N
+2	RELATION	actor.org_unit_type	aout	\N	\N	aout	1	1	INNER	1
+3	RELATION	actor.org_unit	aou	\N	\N	aou	\N	1	\N	\N
+4	RELATION	actor.org_unit_type	aout	\N	\N	aout	\N	1	\N	\N
+5	SUBQUERY	\N	\N	3	\N	aou	\N	1	\N	\N
+6	RELATION	actor.usr	au	\N	\N	au	\N	1	\N	\N
+7	SUBQUERY	\N	\N	3	\N	aou	6	1	INNER	14
+8	RELATION	\N	aou	\N	\N	aou	\N	1	\N	\N
+9	RELATION	actor.usr	au	\N	\N	au	\N	1	\N	\N
+10	FUNCTION	\N	\N	\N	46	\N	\N	1	\N	\N
+\.
+
+
+ALTER TABLE from_relation ENABLE TRIGGER ALL;
+
+--
+-- Data for Name: function_param_def; Type: TABLE DATA; Schema: query; Owner: evergreen
+--
+
+ALTER TABLE function_param_def DISABLE TRIGGER ALL;
+
+COPY function_param_def (id, function_id, seq_no, datatype) FROM stdin;
+\.
+
+
+ALTER TABLE function_param_def ENABLE TRIGGER ALL;
+
+--
+-- Data for Name: function_sig; Type: TABLE DATA; Schema: query; Owner: evergreen
+--
+
+ALTER TABLE function_sig DISABLE TRIGGER ALL;
+
+COPY function_sig (id, function_name, return_type, is_aggregate) FROM stdin;
+1	upper	13	f
+2	actor.org_unit_ancestors	\N	f
+4	COUNT	\N	t
+5	CURRENT_DATE	19	f
+3	EXTRACT	7	f
+6	TRIM	13	f
+\.
+
+
+ALTER TABLE function_sig ENABLE TRIGGER ALL;
+
+--
+-- Data for Name: order_by_item; Type: TABLE DATA; Schema: query; Owner: evergreen
+--
+
+ALTER TABLE order_by_item DISABLE TRIGGER ALL;
+
+COPY order_by_item (id, stored_query, seq_no, expression) FROM stdin;
+3	10	1	5
+4	10	2	2
+\.
+
+
+ALTER TABLE order_by_item ENABLE TRIGGER ALL;
+
+--
+-- Data for Name: query_sequence; Type: TABLE DATA; Schema: query; Owner: evergreen
+--
+
+ALTER TABLE query_sequence DISABLE TRIGGER ALL;
+
+COPY query_sequence (id, parent_query, seq_no, child_query) FROM stdin;
+3	2	1	1
+4	2	2	1
+\.
+
+
+ALTER TABLE query_sequence ENABLE TRIGGER ALL;
+
+--
+-- Data for Name: record_column; Type: TABLE DATA; Schema: query; Owner: evergreen
+--
+
+ALTER TABLE record_column DISABLE TRIGGER ALL;
+
+COPY record_column (id, from_relation, seq_no, column_name, column_type) FROM stdin;
+\.
+
+
+ALTER TABLE record_column ENABLE TRIGGER ALL;
+
+--
+-- Data for Name: select_item; Type: TABLE DATA; Schema: query; Owner: evergreen
+--
+
+ALTER TABLE select_item DISABLE TRIGGER ALL;
+
+COPY select_item (id, stored_query, seq_no, expression, column_alias, grouped_by) FROM stdin;
+1	1	1	2	id	f
+2	1	2	3	name	f
+3	1	3	4	short_name	f
+6	4	2	9	\N	f
+5	4	1	10	\N	f
+7	5	1	10	\N	f
+8	6	1	12	\N	f
+4	3	1	12	\N	f
+9	7	1	12	goober	f
+10	8	1	10	\N	f
+11	9	1	16	\N	f
+12	10	1	2	id	f
+13	10	2	5	parent	f
+14	10	3	4	short_name	f
+15	11	1	2	id	f
+16	12	1	2	\N	f
+17	12	2	3	\N	f
+18	12	3	4	\N	f
+19	12	4	19	\N	f
+20	12	5	5	\N	f
+21	13	1	2	\N	f
+22	13	2	3	\N	f
+23	13	3	4	\N	f
+24	13	4	19	\N	f
+25	13	5	5	\N	f
+26	14	1	2	\N	f
+27	15	1	2	id	f
+28	16	1	2	id	f
+29	17	1	2	id	f
+30	17	2	3	name	f
+31	17	3	33	name	f
+32	18	1	2	id	f
+33	18	2	3	id	f
+34	18	4	36	root_name	f
+35	19	1	2	id	f
+36	20	1	13	id	f
+37	20	2	41	create_day	f
+39	21	2	44	how_many	f
+38	21	1	5	parent	t
+40	23	1	48	\N	f
+41	22	1	44	how_many	f
+42	22	2	5	parent	t
+43	20	3	49	today	f
+45	24	2	53	Branch sequence	f
+46	24	1	2	id	f
+47	25	1	59	cast_text	f
+\.
+
+
+ALTER TABLE select_item ENABLE TRIGGER ALL;
+
+--
+-- Data for Name: stored_query; Type: TABLE DATA; Schema: query; Owner: evergreen
+--
+
+ALTER TABLE stored_query DISABLE TRIGGER ALL;
+
+COPY stored_query (id, type, use_all, use_distinct, from_clause, where_clause, having_clause, limit_count, offset_count) FROM stdin;
+1	SELECT	f	f	1	7	\N	\N	\N
+2	UNION	f	f	\N	\N	\N	\N	\N
+3	SELECT	f	f	3	8	\N	\N	\N
+4	SELECT	f	f	4	\N	\N	\N	\N
+5	SELECT	f	f	4	11	\N	\N	\N
+6	SELECT	f	f	5	\N	\N	\N	\N
+7	SELECT	f	f	6	\N	\N	\N	\N
+8	SELECT	f	f	4	15	\N	\N	\N
+9	SELECT	f	f	3	\N	\N	\N	\N
+10	SELECT	f	f	3	\N	\N	\N	\N
+13	SELECT	f	f	8	21	\N	\N	\N
+14	SELECT	f	f	3	22	\N	\N	\N
+15	SELECT	f	f	3	27	\N	\N	\N
+16	SELECT	f	f	3	32	\N	\N	\N
+17	SELECT	f	f	3	32	\N	\N	\N
+18	SELECT	f	f	3	35	\N	\N	\N
+19	SELECT	f	f	3	38	\N	\N	\N
+20	SELECT	f	f	9	\N	\N	\N	\N
+21	SELECT	f	f	3	\N	\N	\N	\N
+23	SELECT	f	f	10	\N	\N	\N	\N
+22	SELECT	f	f	3	\N	\N	\N	\N
+24	SELECT	f	f	3	\N	\N	\N	\N
+25	SELECT	f	f	3	\N	\N	\N	\N
+12	SELECT	f	f	8	18	\N	\N	\N
+11	SELECT	f	f	8	\N	\N	60	58
+\.
+
+
+ALTER TABLE stored_query ENABLE TRIGGER ALL;
+
+--
+-- Data for Name: subfield; Type: TABLE DATA; Schema: query; Owner: evergreen
+--
+
+ALTER TABLE subfield DISABLE TRIGGER ALL;
+
+COPY subfield (id, composite_type, seq_no, subfield_type) FROM stdin;
+\.
+
+
+ALTER TABLE subfield ENABLE TRIGGER ALL;
+
+--
+-- PostgreSQL database dump complete
+--
+
diff --git a/docs/TechRef/qstore/query_schema.odt b/docs/TechRef/qstore/query_schema.odt
new file mode 100644
index 0000000..823fa80
Binary files /dev/null and b/docs/TechRef/qstore/query_schema.odt differ
diff --git a/docs/TechRef/qstore/stored_queries.txt b/docs/TechRef/qstore/stored_queries.txt
new file mode 100644
index 0000000..bdf84e7
--- /dev/null
+++ b/docs/TechRef/qstore/stored_queries.txt
@@ -0,0 +1,316 @@
+Stored Queries
+
+1: JOIN
+
+SELECT
+   "aou".id AS "id",
+   "aou".name AS "name",
+   "aou".shortname AS "short_name"
+FROM
+   actor.org_unit AS "aou"
+      INNER JOIN actor.org_unit_type AS "aout"
+         ON TRUE
+WHERE
+   "aou".parent_ou > 3;
+
+------------------------------------------------------------
+2: UNION
+
+SELECT
+   "aou".id AS "id",
+   "aou".name AS "name",
+   "aou".shortname AS "short_name"
+FROM
+   actor.org_unit AS "aou"
+      INNER JOIN actor.org_unit_type AS "aout"
+         ON TRUE
+WHERE
+   "aou".parent_ou > 3
+UNION
+SELECT
+   "aou".id AS "id",
+   "aou".name AS "name",
+   "aou".shortname AS "short_name"
+FROM
+   actor.org_unit AS "aou"
+      INNER JOIN actor.org_unit_type AS "aout"
+         ON TRUE
+WHERE
+   "aou".parent_ou > 3;
+
+-----------------------------------------------------------
+3: Simple query (to be used elsewhere as a subquery)
+
+SELECT
+   "aou".ou_type
+FROM
+   actor.org_unit AS "aou"
+WHERE
+   "aou".id = 3;
+
+-------------------------------------------------------------
+4: SELECTing a subquery
+
+SELECT
+   "aout".id,
+   (
+      SELECT
+         "aou".ou_type
+      FROM
+         actor.org_unit AS "aou"
+      WHERE
+         "aou".id = 3
+   )
+FROM
+   actor.org_unit_type AS "aout";
+
+--------------------------------------------------------------
+5: IN clause with a subquery
+
+SELECT
+   "aout".id
+FROM
+   actor.org_unit_type AS "aout"
+WHERE
+   "aout".id IN (
+      SELECT
+         "aou".ou_type
+      FROM
+         actor.org_unit AS "aou"
+      WHERE
+         "aou".id = 3
+   );
+
+---------------------------------------------------------------
+6: Subquery in the FROM clause
+
+SELECT
+   "aou".ou_type
+FROM
+   (
+      SELECT
+         "aou".ou_type
+      FROM
+         actor.org_unit AS "aou"
+      WHERE
+         "aou".id = 3
+   ) AS "aou";
+
+----------------------------------------------------------------
+7: JOINing to a subquery
+
+SELECT
+   "aou".ou_type AS "goober"
+FROM
+   actor.usr AS "au"
+      INNER JOIN (
+         SELECT
+            "aou".ou_type
+         FROM
+            actor.org_unit AS "aou"
+         WHERE
+            "aou".id = 3
+      ) AS "aou"
+         ON "au".id = "aou".ou_type;
+
+----------------------------------------------------------------
+8: EXISTS clause
+
+SELECT
+   "aout".id
+FROM
+   actor.org_unit_type AS "aout"
+WHERE
+   EXISTS (
+      SELECT
+         "aou".ou_type
+      FROM
+         actor.org_unit AS "aou"
+      WHERE
+         "aou".id = 3
+   );
+
+----------------------------------------------------------------
+9: SELECTing a wild card
+
+SELECT
+   "aou".*
+FROM
+   actor.org_unit AS "aou";
+
+------------------------------------------------------------------
+10: ORDER BY clause
+
+SELECT
+   "aou".id AS "id",
+   "aou".parent_ou AS "parent",
+   "aou".shortname AS "short_name"
+FROM
+   actor.org_unit AS "aou"
+ORDER BY
+   "aou".parent_ou,
+   "aou".id;
+
+--------------------------------------------------------------------
+11: Looking up table name in IDL
+
+SELECT
+   "aou".id AS "id"
+FROM
+   actor.org_unit AS "aou";
+
+--------------------------------------------------------------------
+12: numeric bind variable (also works if default value is available)
+
+SELECT
+   "aou".id,
+   "aou".name,
+   "aou".shortname,
+   "aou".opac_visible,
+   "aou".parent_ou
+FROM
+   actor.org_unit AS "aou"
+WHERE
+   "aou".id = :ou;
+
+--------------------------------------------------------------------
+13: string bind variable (using default value 'BRE' for :shortname)
+
+SELECT
+   "aou".id,
+   "aou".name,
+   "aou".shortname,
+   "aou".opac_visible,
+   "aou".parent_ou
+FROM
+   actor.org_unit AS "aou"
+WHERE
+   "aou".shortname = 'BR3';
+
+--------------------------------------------------------------------
+14: IS NULL expression
+
+SELECT
+   "aou".id
+FROM
+   actor.org_unit AS "aou"
+WHERE
+   "aou".parent_ou IS NULL;
+
+--------------------------------------------------------------------
+15: Series expression (chain of ORs)
+
+SELECT
+   "aou".id AS "id"
+FROM
+   actor.org_unit AS "aou"
+WHERE
+   "aou".parent_ou IS NULL
+   OR "aou".email IS NULL
+   OR "aou".holds_address IS NULL;
+
+--------------------------------------------------------------------
+16: IN list
+
+SELECT
+   "aou".id AS "id"
+FROM
+   actor.org_unit AS "aou"
+WHERE
+   "aou".parent_ou IN (1, 3, 6);
+
+--------------------------------------------------------------------
+17: Function call
+
+SELECT
+   "aou".id AS "id",
+   "aou".name AS "name",
+   upper("aou".name) AS "name"
+FROM
+   actor.org_unit AS "aou"
+WHERE
+   "aou".parent_ou IN (1, 3, 6);
+
+--------------------------------------------------------------------
+18: Function call with subfield
+
+SELECT
+   "aou".id AS "id",
+   "aou".name AS "id",
+   (actor.org_unit_ancestors("aou".id))."name" AS "root_name"
+FROM
+   actor.org_unit AS "aou"
+WHERE
+   "aou".id = 3;
+
+--------------------------------------------------------------------
+19: BETWEEN expression
+
+SELECT
+   "aou".id AS "id"
+FROM
+   actor.org_unit AS "aou"
+WHERE
+   "aou".parent_ou BETWEEN 1 AND 4;
+
+--------------------------------------------------------------------
+20: EXTRACT and CURRENT_DATE functions
+
+SELECT
+   "au".id AS "id",
+   EXTRACT(DOW FROM "au".create_date) AS "create_day",
+   CURRENT_DATE  AS "today"
+FROM
+   actor.usr AS "au";
+
+--------------------------------------------------------------------
+21: GROUP BY, with aggregate function last
+
+SELECT
+   "aou".parent_ou AS "parent",
+   COUNT(1) AS "how_many"
+FROM
+   actor.org_unit AS "aou"
+GROUP BY 1;
+
+--------------------------------------------------------------------
+22: GROUP BY, with aggregate function first
+
+SELECT
+   COUNT(1) AS "how_many",
+   "aou".parent_ou AS "parent"
+FROM
+   actor.org_unit AS "aou"
+GROUP BY 2;
+
+--------------------------------------------------------------------
+23: Function in the FROM clause
+
+SELECT
+   *
+FROM
+   upper('goober');
+
+--------------------------------------------------------------------
+24: CASE expression
+
+SELECT
+   "aou".id AS "id",
+   CASE "aou".id
+      WHEN 1
+         THEN 'First'
+      WHEN 2
+         THEN 'Second'
+      ELSE
+         'Other'
+   END AS "Branch sequence"
+FROM
+   actor.org_unit AS "aou";
+
+--------------------------------------------------------------------
+25: CAST expression
+
+SELECT
+   CAST ("aou".id AS TEXT) AS "cast_text"
+FROM
+   actor.org_unit AS "aou";
diff --git a/docs/TechRef/qstore/test_qstore.txt b/docs/TechRef/qstore/test_qstore.txt
new file mode 100644
index 0000000..6210767
--- /dev/null
+++ b/docs/TechRef/qstore/test_qstore.txt
@@ -0,0 +1,48 @@
+test_qstore
+
+This command-line utility exercises most of the code used in the qstore server, but
+without the complications of sending and receiving OSRF messages.
+
+Synopsis:
+
+test_qstore  [options]  query_id
+
+Query_id is the id of a row in the query.stored_query table, defining a stored query.
+
+The program reads the specified row in query.stored_query, along with associated rows
+in other tables, and displays the corresponding query as an SQL command.  Optionally it
+may execute the query, display the column names of the query result, and/or display the
+bind variables.
+
+In order to connect to the database, test_qstore uses various connection parameters
+that may be specified on the command line.  Any connection parameter not specified
+reverts to a plausible default.
+
+The database password may be read from a specified file or entered from the keyboard.
+
+Options:
+
+-b  Boolean; Display the name of any bind variables, and their default values.
+
+-D  Specifies the name of the database driver; defaults to "pgsql".
+
+-c  Boolean; display column names of the query results, as assigned by PostgreSQL.
+
+-d  Specifies the database name; defaults to "evergreen".
+
+-h  Specifies the hostname of the database; defaults to "localhost".
+
+-i  Specifies the name of the IDL file; defaults to "/openils/conf/fm_IDL.xml".
+
+-p  Specifies the port number of the database; defaults to 5432.
+
+-u  Specifies the database user name; defaults to "evergreen".
+
+-v  Boolean; Run in verbose mode, spewing various detailed messages.  This option is not
+	likely to be useful unless you are troubleshooting the code that loads the stored
+	query.
+
+-w  Specifies the name of a file containing the database password (no default).
+
+-x  Boolean: Execute the query and display the results.
+

-----------------------------------------------------------------------

Summary of changes:
 docs/TechRef/qstore/README             |   60 +++
 docs/TechRef/qstore/qstore.adoc        |  390 +++++++++++++++
 docs/TechRef/qstore/qstore.odt         |  Bin 0 -> 29471 bytes
 docs/TechRef/qstore/query_dump.sh      |    9 +
 docs/TechRef/qstore/query_dump.sql     |  393 +++++++++++++++
 docs/TechRef/qstore/query_schema.adoc  |  856 ++++++++++++++++++++++++++++++++
 docs/TechRef/qstore/query_schema.odt   |  Bin 0 -> 37048 bytes
 docs/TechRef/qstore/stored_queries.txt |  316 ++++++++++++
 docs/TechRef/qstore/test_qstore.txt    |   48 ++
 9 files changed, 2072 insertions(+), 0 deletions(-)
 create mode 100644 docs/TechRef/qstore/README
 create mode 100644 docs/TechRef/qstore/qstore.adoc
 create mode 100644 docs/TechRef/qstore/qstore.odt
 create mode 100755 docs/TechRef/qstore/query_dump.sh
 create mode 100644 docs/TechRef/qstore/query_dump.sql
 create mode 100644 docs/TechRef/qstore/query_schema.adoc
 create mode 100644 docs/TechRef/qstore/query_schema.odt
 create mode 100644 docs/TechRef/qstore/stored_queries.txt
 create mode 100644 docs/TechRef/qstore/test_qstore.txt


hooks/post-receive
-- 
Evergreen ILS


More information about the open-ils-commits mailing list