diff --git a/CHANGELOG.md b/CHANGELOG.md index ba0ec46..1d1da3e 100644 --- a/CHANGELOG.md +++ b/CHANGELOG.md @@ -1,5 +1,19 @@ +# Changelog 1.33.10 +## Changes to S-SQL +- Added :call operator to s-sql (so that you can use the s-sql syntax to call a Postgresql procedure) and substantial more s-sql examples in the documentation. + +- Fixed bug in create-composite-type that disallowed certain multiword parameters +- Fixed bug in to-type-name and sql-type-name that precluded custom types +- Fixed bug in :create-table ability to create generated columns. +- Fixed bug in to-tsvector calls + +- Added cube operators + +- Added more documentation examples and tests for s-sql + # Changelog 1.33.9 Fixed bug in thread handling when using binary parameters + # Changelog 1.33.8 Dollar Quoted tags are allowed in files. Prior to Postmodern version 1.33.8 only diff --git a/README.md b/README.md index e4a3a7d..3583e5f 100644 --- a/README.md +++ b/README.md @@ -4,7 +4,7 @@ A Common Lisp PostgreSQL programming interface --- -Version 1.33.9 +Version 1.33.10 Postmodern is a Common Lisp library for interacting with [PostgreSQL](http://www.postgresql.org) databases. It is under active development. Features are: @@ -20,6 +20,7 @@ The biggest differences between this library and CLSQL/CommonSQL or cl-dbi are t --- +- [Reference](#reference) - [Dependencies](#dependencies) - [License](#dependencies) - [Download and installation](#download-and-installation) @@ -32,10 +33,31 @@ The biggest differences between this library and CLSQL/CommonSQL or cl-dbi are t - [Feature Requests](#feature-requests) - [Resources](#resources) - [Running tests](#running-tests) -- [Reference](#reference) - [Caveats and to-dos](#caveats-and-to-dos) - [Resources](#resources) +## Reference + +--- + +The reference manuals for the different components of Postmodern are kept in separate files. For using the library in the most straightforward way, you only really need to read the Postmodern reference and glance over the S-SQL reference. The simple-date reference explains the time-related data types included in Postmodern, and the CL-postgres reference might be useful if you just want a low-level library for talking to a PostgreSQL server. + +- [Postmodern - Index Page](https://marijnhaverbeke.nl/postmodern/index.html) +- [Postmodern](https://marijnhaverbeke.nl/postmodern/postmodern.html) +- [S-SQL](https://marijnhaverbeke.nl/postmodern/s-sql.html) +- [Simple-date](https://marijnhaverbeke.nl/postmodern/simple-date.html) +- [CL-postgres](https://marijnhaverbeke.nl/postmodern/cl-postgres.html) + +Some specific topics in more detail: + +- [Array Notes](https://marijnhaverbeke.nl/postmodern/array-notes.html) +- [Creating Tables](https://marijnhaverbeke.nl/postmodern/create-tables.html) +- [Dao Classes](https://marijnhaverbeke.nl/postmodern/dao-classes.html) +- [Dynamic Queries](https://marijnhaverbeke.nl/postmodern/dynamic-queries.html) +- [Interval Notes](https://marijnhaverbeke.nl/postmodern/interval-notes.html) +- [Isolation Notes](https://marijnhaverbeke.nl/postmodern/isolation-notes.html) +- [S-SQL Examples](https://marijnhaverbeke.nl/postmodern/s-sql-examples.html) + ## Dependencies --- @@ -437,7 +459,7 @@ Next, to demonstrate a bit more of the S-SQL syntax, here is the query the utili sql is a macro that will simply compile a query, it can be useful for seeing how your queries are expanded or if you want to do something unexpected with them. -As you can see, lists starting with keywords are used to express SQL commands and operators (lists starting with something else will be evaluated and then inserted into the query). Quoted symbols name columns or tables (keywords can also be used but might introduce ambiguities). The syntax supports subqueries, multiple joins, stored procedures, etc. See the S-SQL reference manual for a complete treatment. +As you can see, lists starting with keywords are used to express SQL commands and operators (lists starting with something else will be evaluated and then inserted into the query). Quoted symbols name columns or tables (keywords can also be used but might introduce ambiguities). The syntax supports subqueries, multiple joins, stored procedures, etc. See the S-SQL reference manual for a complete treatment and the S-SQL Example pages. Finally, here is an example of the use of prepared statements: @@ -461,28 +483,6 @@ Postmodern can use either md5 or scram-sha-256 authentication. Scram-sha-256 aut Other authentication methods have not been tested. Please let us know if there is a authentication method that you believe should be considered. -## Reference - ---- - -The reference manuals for the different components of Postmodern are kept in separate files. For using the library in the most straightforward way, you only really need to read the Postmodern reference and glance over the S-SQL reference. The simple-date reference explains the time-related data types included in Postmodern, and the CL-postgres reference might be useful if you just want a low-level library for talking to a PostgreSQL server. - -- [Postmodern - Index Page](https://marijnhaverbeke.nl/postmodern/index.html) -- [Postmodern](https://marijnhaverbeke.nl/postmodern/postmodern.html) -- [S-SQL](https://marijnhaverbeke.nl/postmodern/s-sql.html) -- [Simple-date](https://marijnhaverbeke.nl/postmodern/simple-date.html) -- [CL-postgres](https://marijnhaverbeke.nl/postmodern/cl-postgres.html) - -Some specific topics in more detail: - -- [Array Notes](https://marijnhaverbeke.nl/postmodern/array-notes.html) -- [Creating Tables](https://marijnhaverbeke.nl/postmodern/create-tables.html) -- [Dao Classes](https://marijnhaverbeke.nl/postmodern/dao-classes.html) -- [Dynamic Queries](https://marijnhaverbeke.nl/postmodern/dynamic-queries.html) -- [Interval Notes](https://marijnhaverbeke.nl/postmodern/interval-notes.html) -- [Isolation Notes](https://marijnhaverbeke.nl/postmodern/isolation-notes.html) - - ## Data Types --- @@ -664,7 +664,8 @@ It is highly suggested that you do not use words that are reserved by Postgresql ## Feature Requests -Postmodern is under active development so issues and feature requests should + +Postmodern is under periodic development so issues and feature requests should be flagged on [Postmodern's site on github](https://github.com/marijnh/Postmodern). ## Resources diff --git a/ROADMAP.md b/ROADMAP.md deleted file mode 100644 index a61b711..0000000 --- a/ROADMAP.md +++ /dev/null @@ -1,74 +0,0 @@ -# Possible Roadmap -Postmodern is a common lisp support library for the postgresql database. It makes -no attempt to be database agnostic. You can think of postmodern as having three components -- cl-postgres : a low level interface for communicating with a postgresql database server -- s-sql : a lispy dsl providing possibly a more comfortable way to write sql queries, and -- postmodern : a package which extends the cl-postgres interface. Comments are solicited on - whether the cl-postgres and postmodern packages should be combined. - -This draft longterm roadmap is a work in progress on issue resolution and additional -functionality under consideration. Requests for different priorities are expected and -welcomed, particularly by anyone willing to work on the item. - -No guarantee is given with respect to resolution or timing on any item. - -## Sql support -- [ ] UUID (see e.g https://github.com/michaeljforster/cl-postgres-plus-uuid) - Postgresql has a uuid extension. A database owner needs to add the extension manually to the specific database, calling: - create extension if not exists "uuid-ossp"; - A uuid can then be generated in postmodern by calling (query (:select (:uuid-generate-v1))) -- [ ] Transition tables for triggers (postgresql 10) -- [ ] Hash Indexes (postgresql 10, See https://blog.2ndquadrant.com/postgresql-10-identity-columns/, - https://www.depesz.com/2017/04/10/waiting-for-postgresql-10-identity-columns/) -- [ ] Full text search with phrases (postgresql 9.6 and additional functionality in 12.0) -- [ ] WITH CHECK clause - Auto-updatable views can now specify whether an INSERT or UPDATE - would change the state of the row so that it would no longer be visible in the view. - Using WITH CHECK OPTION will prevent any such changes from occuring. (postgresql 9.4) -- [ ] Table Creation with different indexes (various postgresql version additions) -- [ ] Generated columns - see https://pgdash.io/blog/postgres-12-generated-columns.html -- [ ] Postgresql regular expression support - see https://www.postgresql.org/docs/current/static/pgtrgm.html -- [ ] Create table by selecting from another table. - -## Data type support -- [ ] json, jsonb (postgresql 9.4, full text search support in postgresql 10) See - https://github.com/gtod/postgres-json/blob/master/postgres/s-sql.lisp - Include exporting to json strings acceptable to the different common lisp libraries -- [ ] Ranges -- [ ] Postgis -- [ ] XML (see also xmltable in postgresql 10) -- [ ] Enum needs testing and documentation -- [ ] Network Addresses -- [ ] Others? - -## DAO Support -- [ ] Review errors with *ignore-unknown-columns*. Sometimes hangs without raising an error. -- [ ] Type validation - make it easier to use col-type to ensure that a slot value is what the database expects - -## Other Support -- [ ] Migration Support (compare with https://pypi.org/project/alembic/) -- [ ] Named Prepared Statement explicit arglist -- [ ] SQL Read Table Review (comments requested on any work that should be done here) -- [ ] Row Reader Review (comments requested on any work that should be done here) -- [X] Allow parameters to be passed as binary to postgresql - -## Connections/Reconnections and Transactions -- [ ] Ensure transactions can deal with reconnections/restarts -- [ ] IPV6 connections - -## Documentation -- [ ] Setup -- [ ] Usage examples for sql users -- [ ] Usage examples for non-sql users -- [ ] Creation of new datatypes -- [ ] Pooling with external pooling applications - -## Armed Bear Issues -- [ ] What is the problem with :null -- [ ] Armed Bear issues with unicode. See e.g. icelandic cities in test-s-sql - -## Security Audit - -## Long Range (Likely Never) -- [ ] Consider extending dao into more ORM capability -- [ ] Multi-Cluster Support -- [ ] Replication Support diff --git a/doc/calling-postgresql-stored-functions.html b/doc/calling-postgresql-stored-functions.html new file mode 100644 index 0000000..706c22f --- /dev/null +++ b/doc/calling-postgresql-stored-functions.html @@ -0,0 +1,671 @@ + + + + + + +Calling Postgresql Stored Functions and Procedures + + + + + + + +
+
+

Calling Postgresql Stored Functions and Procedures

+
+ +
+

S-SQL Examples Home Page

+
+ + + +++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ + + + + + + + + + + + + + + + + + + + + + + + + + + + + +
ABCDEFGHIJKLMNOPRSTUVWSpecial CharactersCalling Postgresql Stored Functions and Procedures
+
+
+ +
+

Postgresql Stored Functions and Procedures

+
+

+Postgresql (Not Postmodern) stored functions and procedures are confusing. We can start by setting up a very simple table t1 and insert a couple of values: +

+
+
(query (:create-table 't1
+                      ((id :type integer :primary-key t)
+                       (x :type integer))))
+
+(query (:insert-rows-into 't1
+        :columns 'id 'x
+        :values '((1 1)(2 2)))
+
+
+
+
+ +
+

Overview of the differences between Postgresql Stored Functions and Postgresql Stored Procedures

+
+
+
+

Functions:

+
+
    +
  1. can be called inside a query (select func() from foo)
  2. + +
  3. generally return a result
  4. + +
  5. must return a single set
  6. + +
  7. are scoped to a transaction
  8. + +
  9. cannot commit and rollback transactions
  10. + +
  11. are called using a select
  12. +
+
+
+ +
+

Procedures:

+
+
    +
  1. can not be called inside a query
  2. + +
  3. typically don’t return results except for maybe error code. There is limited capabilities in Postgresql 13 to return values using INOUT parameters (more below).
  4. + +
  5. can commit and rollback transactions
  6. + +
  7. can flush the transaction (essentially a COMMIT; followed by a BEGIN;) within the procedure. This is the most important part; it allows for various kinds of things that are dangerous or impossible with functions (for example, a routine that never terminates..
  8. + +
  9. are called using call
  10. +
+ +

+The rule of thumb: if you don't need to manage transactions from within, you probably want to use a function instead of a procedure. +

+
+
+
+
+

Stored Functions

+
+

+The Postgresql documentation for stored functions can be found here. Functions are atomic in Postgresql and automatically run inside their own transaction unless called within an outer transaction. They always run inside a single transaction and succeed or fail completely. Consequently, one cannot begin or commit transactions within the function. And commands like VACUUM, CREATE DATABASE, or CREATE INDEX CONCURRENTLY which do not run in a transaction context are not allowed. +

+
+ +
+

Variation 1 with RETURNS SETOF T1

+
+

+First we create a postgresql stored function which updates a specified row and returns the id and x values for that row, then call that function, first in plain sql then in s-sql. Note that in this variation, the second line of the function specifies that it returns a setof t1. S-SQL does not have a sub-dialect for plpgsql, so we need to use the text version: +

+
+
(query "CREATE OR REPLACE FUNCTION set_x_function1 (fromid INT, newx INT)
+         RETURNS setof t1 as $$
+         BEGIN
+         UPDATE t1 SET x=newx WHERE id=fromid;
+         RETURN QUERY select t1.id, t1.x from t1 where t1.id=fromid;
+         END;
+         $$ LANGUAGE plpgsql;")
+
+
+
+
+

Plain SQL

+
+

+The plain sql call for the function would look like this: +

+
+
(query "SELECT id, x from set_x_function1(1, 3)")
+
+((1 3))
+
+(query "select * from t1") ; confirming the change happened in the database
+
+((2 2) (1 3))
+
+
+
+
+
+

S-SQL Call

+
+

+Now calling the function using the s-sql dsl. We will show two variations and then separately a third variation which has some issues between Postgresql and Postmodern. +

+
+
(query (:select 'id 'x :from (:set_x_function1 1 4)))
+
+((1 4))
+
+
+
+
+
+ +
+

Variation 2 with RETURNS TABLE

+
+

+This is effectively the same as Variation 1's use of SETOF tablename, but declares the table structure inline instead of referencing an existing object, so joins and such will still work. +

+ +

+We are going to vary the function slightly here, specifically in that second line, then call the function using a plain sql query and then an s-sql query. Also note that the calling query needs to be referencing the column names in the table being returned.: +

+
+
  (query "CREATE OR REPLACE FUNCTION set_x_function2 (fromid INT, newx INT)
+        RETURNS table (tid int, tx int) as $$
+        BEGIN
+        UPDATE t1 SET x=newx WHERE id=fromid;
+        RETURN QUERY select t1.id, t1.x from t1 where t1.id=fromid;
+        END;
+        $$ LANGUAGE plpgsql;")
+
+(query "SELECT tid, tx from set_x_function2(1, 16)")
+
+((1 16))
+
+(query (:select 'tid 'tx :from (:set_x_function2 1 15)))
+
+((1 15))
+
+
+ +

+Out of curiosity, what would happen if we just selected the calling function rather than specifying the columns that we want? +

+
+
(query (:select (:set_x_function 1 17)))
+
+(("(1,17)"))
+
+
+ +

+We got back a sublist containing a string rather sublist containing two integers, probably not what we wanted. +

+ +

+Now consider the related but not quite the same Postgresql Stored Procedures. +

+
+
+
+
+

Stored Procedures

+
+

+The Postgresql documentation for procedures is found here and you can notice that the format is slightly different.. SQL procedures can begin and end transactions. +

+ +

+Similar to the stored function we just looked at, lets create a postgresql stored procedure which simply updates the x field in a specified row and we won't worry about getting a return value yet. +

+
+
+

Example 1

+
+
+
(query "CREATE OR REPLACE PROCEDURE set_x_procedure1 (fromid INT, newx INT)
+      LANGUAGE plpgsql
+      AS $$
+      BEGIN
+        UPDATE t1 SET x=newx WHERE id=fromid;
+        COMMIT;
+      END;
+      $$ ;")
+
+
+
+ +

+If you were going to call this procedure from psql it would look like: +

+
+
call set_x_procedure1(1,3);
+
+select * from t1;
+
+ id | x
+
+----+---
+
+  2 | 2
+
+  1 | 3
+
+(2 rows)
+
+
+
+
+
+
+

Pre Postmodern version 1.33.10 (using plain SQL)

+
+

+Postmodern has an s-sql :call operator as of version 1.33.10. +Pre-version 1.33.10, you would simply use a sql string: +

+
+
(query "call set_x_procedure1(1,13)")
+
+((2 2) (1 13))
+
+
+
+
+
+

Post Postmodern version 1.33.9 (:call operator)

+
+

+As of version 1.33.10, you can use s-sql as you might expect: +

+
+
(query (:call 'set_x_procedure1 1 13))
+
+((2 2) (1 13))
+
+
+

+or, using variables +

+
+
(let ((a 1) (b 2) (p 'set_x_procedure1))
+  (query (:call p a b 3)))
+
+((2 2) (1 13))
+
+
+
+
+
+

Example 2

+
+

+We change the parameter list to the stored procedure slightly to make fromid as an inout parameter. Calling the procedure will now return all parameters with INOUT specified: +

+
+
(query "CREATE OR REPLACE PROCEDURE set_x_procedure2 (INOUT fromid INT, newx INT)
+        LANGUAGE plpgsql
+        AS $$
+        BEGIN
+          UPDATE t1 SET x=newx WHERE id=fromid;
+          COMMIT;
+        END;
+        $$ ;")
+
+
+
+
+

Plain SQL call

+
+
+
  (query "call set_x_procedure2(1,11)" :single)
+
+1
+
+
+
+
+
+

S-SQL with :call operator

+
+
+
(query (:call 'set_x_procedure2 1 11) :single)
+
+1
+
+
+ +

+In the following example, we demonstrate that you can apply INOUT to multiple parameters but since we are changing the return type of an existing function (the row type defined by the out parameters are different), we need to drop the procedure first. +

+
+
(query "DROP PROCEDURE set_x_procedure2(integer,integer)")
+(query "CREATE OR REPLACE PROCEDURE set_x_procedure2 (INOUT fromid INT, INOUT    newx INT)
+        LANGUAGE plpgsql
+        AS $$
+        BEGIN
+          UPDATE t1 SET x=newx WHERE id=fromid;
+          COMMIT;
+        END;
+        $$ ;")
+
+
+
+
+
+

Plain SQL call

+
+
+
  (query "call set_x_procedure2(1,11)")
+
+((1 11))
+
+
+
+
+
+

S-SQL with :call operator

+
+
+
(query (:call 'set_x_procedure2 1 13))
+
+((1 13))
+
+
+
+
+
+
+
+ + \ No newline at end of file diff --git a/doc/calling-postgresql-stored-functions.org b/doc/calling-postgresql-stored-functions.org new file mode 100644 index 0000000..2688a66 --- /dev/null +++ b/doc/calling-postgresql-stored-functions.org @@ -0,0 +1,268 @@ +#+TITLE: Calling Postgresql Stored Functions and Procedures +#+OPTIONS: num:nil +#+HTML_HEAD: +#+HTML_HEAD: +#+OPTIONS: ^:nil + +* [[file:s-sql-examples.org][S-SQL Examples Home Page]] +| [[file:s-sql-a.org][A]]| [[file:s-sql-b.org][B]]| [[file:s-sql-c.org][C]]| [[file:s-sql-d.org][D]]| [[file:s-sql-e.org][E]]| [[file:s-sql-f.org][F]]| [[file:s-sql-g.org][G]]| [[file:s-sql-h.org][H]]| [[file:s-sql-i.org][I]]| [[file:s-sql-j.org][J]]| [[file:s-sql-k.org][K]]| [[file:s-sql-l.org][L]]| [[file:s-sql-m.org][M]]| [[file:s-sql-n.org][N]]| [[file:s-sql-o.org][O]]| [[file:s-sql-p.org][P]]| [[file:s-sql-r.org][R]]| [[file:s-sql-s.org][S]]| [[file:s-sql-t.org][T]]| [[file:s-sql-u.org][U]]| [[file:s-sql-v.org][V]]| [[file:s-sql-w.org][W]]| [[file:s-sql-special-characters.org][Special Characters]] | [[file:calling-postgresql-stored-functions.org][Calling Postgresql Stored Functions and Procedures]]| + +* Postgresql Stored Functions and Procedures + :PROPERTIES: + :CUSTOM_ID: intro + :END: +Postgresql (Not Postmodern) stored functions and procedures are confusing. We can start by setting up a very simple table t1 and insert a couple of values: +#+begin_src lisp + (query (:create-table 't1 + ((id :type integer :primary-key t) + (x :type integer)))) + + (query (:insert-rows-into 't1 + :columns 'id 'x + :values '((1 1)(2 2))) + #+end_src + +* Overview of the differences between Postgresql Stored Functions and Postgresql Stored Procedures + :PROPERTIES: + :CUSTOM_ID: overview + :END: +** Functions: + :PROPERTIES: + :CUSTOM_ID: functions + :END: +1) can be called inside a query (select func() from foo) + +2) generally return a result + +3) must return a single set + +4) are scoped to a transaction + +5) cannot commit and rollback transactions + +6) are called using a select + +** Procedures: + :PROPERTIES: + :CUSTOM_ID: procedures + :END: +1) can not be called inside a query + +2) typically don’t return results except for maybe error code. There is limited capabilities in Postgresql 13 to return values using INOUT parameters (more below). + +3) can commit and rollback transactions + +4) can flush the transaction (essentially a COMMIT; followed by a BEGIN;) within the procedure. This is the most important part; it allows for various kinds of things that are dangerous or impossible with functions (for example, a routine that never terminates.. + +5) are called using call + +The rule of thumb: if you don't need to manage transactions from within, you probably want to use a function instead of a procedure. +* Stored Functions + :PROPERTIES: + :CUSTOM_ID: stored-functions + :END: +The Postgresql documentation for stored functions can be found [[https://www.postgresql.org/docs/current/sql-createfunction.html][here]]. Functions are atomic in Postgresql and automatically run inside their own transaction unless called within an outer transaction. They always run inside a single transaction and succeed or fail completely. Consequently, one cannot begin or commit transactions within the function. And commands like VACUUM, CREATE DATABASE, or CREATE INDEX CONCURRENTLY which do not run in a transaction context are not allowed. + +** Variation 1 with RETURNS SETOF T1 + :PROPERTIES: + :CUSTOM_ID: variation-1 + :END: +First we create a postgresql stored function which updates a specified row and returns the id and x values for that row, then call that function, first in plain sql then in s-sql. Note that in this variation, the second line of the function specifies that it returns a setof t1. S-SQL does not have a sub-dialect for plpgsql, so we need to use the text version: +#+begin_src lisp +(query "CREATE OR REPLACE FUNCTION set_x_function1 (fromid INT, newx INT) + RETURNS setof t1 as $$ + BEGIN + UPDATE t1 SET x=newx WHERE id=fromid; + RETURN QUERY select t1.id, t1.x from t1 where t1.id=fromid; + END; + $$ LANGUAGE plpgsql;") +#+end_src +*** Plain SQL + :PROPERTIES: + :CUSTOM_ID: variation-1-sql + :END: +The plain sql call for the function would look like this: +#+begin_src lisp + (query "SELECT id, x from set_x_function1(1, 3)") + + ((1 3)) + + (query "select * from t1") ; confirming the change happened in the database + + ((2 2) (1 3)) +#+end_src +*** S-SQL Call + :PROPERTIES: + :CUSTOM_ID: variation-1-s-sql + :END: +Now calling the function using the s-sql dsl. We will show two variations and then separately a third variation which has some issues between Postgresql and Postmodern. +#+begin_src lisp + (query (:select 'id 'x :from (:set_x_function1 1 4))) + + ((1 4)) +#+end_src + +** Variation 2 with RETURNS TABLE + :PROPERTIES: + :CUSTOM_ID: variation-2 + :END: +This is effectively the same as Variation 1's use of SETOF tablename, but declares the table structure inline instead of referencing an existing object, so joins and such will still work. + +We are going to vary the function slightly here, specifically in that second line, then call the function using a plain sql query and then an s-sql query. Also note that the calling query needs to be referencing the column names in the table being returned.: +#+begin_src lisp + (query "CREATE OR REPLACE FUNCTION set_x_function2 (fromid INT, newx INT) + RETURNS table (tid int, tx int) as $$ + BEGIN + UPDATE t1 SET x=newx WHERE id=fromid; + RETURN QUERY select t1.id, t1.x from t1 where t1.id=fromid; + END; + $$ LANGUAGE plpgsql;") + +(query "SELECT tid, tx from set_x_function2(1, 16)") + +((1 16)) + +(query (:select 'tid 'tx :from (:set_x_function2 1 15))) + +((1 15)) +#+end_src + +Out of curiosity, what would happen if we just selected the calling function rather than specifying the columns that we want? +#+begin_src lisp + (query (:select (:set_x_function 1 17))) + + (("(1,17)")) +#+end_src + +We got back a sublist containing a string rather sublist containing two integers, probably not what we wanted. + +Now consider the related but not quite the same Postgresql Stored Procedures. +* Stored Procedures + :PROPERTIES: + :CUSTOM_ID: stored-procedures + :END: +The Postgresql documentation for procedures is found here and you can notice that the format is slightly different.. SQL procedures can begin and end transactions. + +Similar to the stored function we just looked at, lets create a postgresql stored procedure which simply updates the x field in a specified row and we won't worry about getting a return value yet. +** Example 1 +#+begin_src lisp + (query "CREATE OR REPLACE PROCEDURE set_x_procedure1 (fromid INT, newx INT) + LANGUAGE plpgsql + AS $$ + BEGIN + UPDATE t1 SET x=newx WHERE id=fromid; + COMMIT; + END; + $$ ;") + +#+end_src + +If you were going to call this procedure from psql it would look like: +#+begin_src sql + call set_x_procedure1(1,3); + + select * from t1; + + id | x + + ----+--- + + 2 | 2 + + 1 | 3 + + (2 rows) + +#+end_src +** Pre Postmodern version 1.33.10 (using plain SQL) + :PROPERTIES: + :CUSTOM_ID: stored-procedures-sql + :END: +Postmodern has an s-sql :call operator as of version 1.33.10. +Pre-version 1.33.10, you would simply use a sql string: +#+begin_src lisp + (query "call set_x_procedure1(1,13)") + + ((2 2) (1 13)) +#+end_src +** Post Postmodern version 1.33.9 (:call operator) + :PROPERTIES: + :CUSTOM_ID: stored-procedures-s-sql + :END: +As of version 1.33.10, you can use s-sql as you might expect: + #+BEGIN_SRC lisp + (query (:call 'set_x_procedure1 1 13)) + + ((2 2) (1 13)) +#+END_SRC +or, using variables +#+begin_src lisp + (let ((a 1) (b 2) (p 'set_x_procedure1)) + (query (:call p a b 3))) + + ((2 2) (1 13)) +#+end_src +** Example 2 + :PROPERTIES: + :CUSTOM_ID: stored-procedures-example-2 + :END: +We change the parameter list to the stored procedure slightly to make fromid as an inout parameter. Calling the procedure will now return all parameters with INOUT specified: +#+begin_src lisp +(query "CREATE OR REPLACE PROCEDURE set_x_procedure2 (INOUT fromid INT, newx INT) + LANGUAGE plpgsql + AS $$ + BEGIN + UPDATE t1 SET x=newx WHERE id=fromid; + COMMIT; + END; + $$ ;") +#+end_src +*** Plain SQL call + :PROPERTIES: + :CUSTOM_ID: stored-procedures-example-2-sql + :END: +#+begin_src lisp + (query "call set_x_procedure2(1,11)" :single) + +1 +#+end_src +*** S-SQL with :call operator + :PROPERTIES: + :CUSTOM_ID: stored-procedures-example-2-s-sql + :END: +#+begin_src lisp + (query (:call 'set_x_procedure2 1 11) :single) + + 1 +#+end_src + +In the following example, we demonstrate that you can apply INOUT to multiple parameters but since we are changing the return type of an existing function (the row type defined by the out parameters are different), we need to drop the procedure first. +#+begin_src lisp + (query "DROP PROCEDURE set_x_procedure2(integer,integer)") + (query "CREATE OR REPLACE PROCEDURE set_x_procedure2 (INOUT fromid INT, INOUT newx INT) + LANGUAGE plpgsql + AS $$ + BEGIN + UPDATE t1 SET x=newx WHERE id=fromid; + COMMIT; + END; + $$ ;") +#+end_src +*** Plain SQL call + :PROPERTIES: + :CUSTOM_ID: stored-procedures-example-2a-sql + :END: +#+begin_src lisp + (query "call set_x_procedure2(1,11)") + +((1 11)) +#+end_src +*** S-SQL with :call operator + :PROPERTIES: + :CUSTOM_ID: stored-procedures-example-2a-s-sql + :END: +#+begin_src lisp + (query (:call 'set_x_procedure2 1 13)) + + ((1 13)) +#+end_src diff --git a/doc/cl-postgres.html b/doc/cl-postgres.html index 8b12929..e2e8db1 100644 --- a/doc/cl-postgres.html +++ b/doc/cl-postgres.html @@ -1,7 +1,7 @@ - + Cl-Postgres Reference Manual @@ -1434,4 +1434,4 @@

method postgresql-notification-pid ( - + \ No newline at end of file diff --git a/doc/index.html b/doc/index.html index 1445e3b..ce47627 100644 --- a/doc/index.html +++ b/doc/index.html @@ -1,7 +1,7 @@ - + Postmodern @@ -202,6 +202,7 @@

Postmodern

Table of Contents

  • Authentication
  • -
  • Reference
  • Data Types
  • -Version 1.33.9 +Version 1.33.10

    @@ -268,6 +268,41 @@

    Table of Contents

    me. Your mileage may vary.

    +
    +

    Reference

    +
    +

    +The reference manuals for the different components of Postmodern are kept +in separate files. For using the library in the most straightforward way, +you only really need to read the Postmodern reference and glance over the +S-SQL reference. The simple-date reference explains the time-related data +types included in Postmodern, and the CL-postgres reference might be useful +if you just want a low-level library for talking to a PostgreSQL server. +

    + + + +

    +Some specific topics in more detail +

    + + +
    +
    +

    Dependencies

    @@ -949,40 +984,6 @@

    Authentication

    -
    -

    Reference

    -
    -

    -The reference manuals for the different components of Postmodern are kept -in separate files. For using the library in the most straightforward way, -you only really need to read the Postmodern reference and glance over the -S-SQL reference. The simple-date reference explains the time-related data -types included in Postmodern, and the CL-postgres reference might be useful -if you just want a low-level library for talking to a PostgreSQL server. -

    - - - -

    -Some specific topics in more detail -

    - - -
    -
    -

    Data Types

    @@ -1513,9 +1514,9 @@

    Timezones and Simple-Date and Loca

    -
    -

    Simple-Date Library Use

    -
    +
    +

    Simple-Date Library Use

    +

    The Simple-date add-on library (not enabled by default) provides types (CLOS classes) for dates, timestamps, and intervals @@ -1637,9 +1638,9 @@

    Simple-Date Library Use

    -
    -

    Local-Time Library Use

    -
    +
    +

    Local-Time Library Use

    +

    For those who want to use local-time, to enable the local-time reader:

    @@ -1796,14 +1797,9 @@

    Reserved Words

    Things that should be implemented

    -Postmodern is under active development so Issues and feature requests should +Postmodern is under active maintenance so issues and feature requests should be flagged on Postmodern's site on github.

    - -

    -Some areas that are currently under consideration can be found in the ROADMAP.md -file. -

    diff --git a/doc/index.org b/doc/index.org index bfa26e6..8e27fdf 100644 --- a/doc/index.org +++ b/doc/index.org @@ -4,7 +4,7 @@ #+HTML_HEAD: #+OPTIONS: ^:nil -Version 1.33.9 +Version 1.33.10 Postmodern is a Common Lisp library for interacting with [[https://postgresql.org][PostgreSQL databases]]. Features are: @@ -22,6 +22,33 @@ extensions like lispy SQL and database access objects in a quite different way. This library was written because the CLSQL approach did not really work for me. Your mileage may vary. +* Reference + :PROPERTIES: + :ID: 27b39236-15ee-42c3-958a-3c9c903c4567 + :CUSTOM_ID: 8993c7bd-4ba2-4080-8c5a-ff90de45eca5 + :END: +The reference manuals for the different components of Postmodern are kept +in separate files. For using the library in the most straightforward way, +you only really need to read the Postmodern reference and glance over the +S-SQL reference. The simple-date reference explains the time-related data +types included in Postmodern, and the CL-postgres reference might be useful +if you just want a low-level library for talking to a PostgreSQL server. + +- [[file:postmodern.html][Postmodern]] +- [[file:s-sql.html][S-SQL]] +- [[file:simple-date.html][Simple-date]] +- [[file:cl-postgres.html][CL-postgres]] + +Some specific topics in more detail + +- [[file:s-sql-examples.html][S-SQL Examples]] +- [[file:array-notes.html][Array-Notes]] +- [[file:create-tables.html][Creating Tables]] +- [[file:dao-classes.html][Database Access Object (Dao) Classes]] +- [[file:dynamic-queries.html][Dynamic Queries]] +- [[file:interval-notes.html][Interval Notes]] +- [[file:isolation-notes.html][Isolation Notes]] + * Dependencies :PROPERTIES: :ID: 216c43d0-57ff-4ae3-a302-6d04a3d79665 @@ -521,32 +548,6 @@ using a connection pooling setup.. Other authentication methods have not been tested. Please let us know if there is a authentication method that you believe should be considered. -* Reference - :PROPERTIES: - :ID: 27b39236-15ee-42c3-958a-3c9c903c4567 - :CUSTOM_ID: 8993c7bd-4ba2-4080-8c5a-ff90de45eca5 - :END: -The reference manuals for the different components of Postmodern are kept -in separate files. For using the library in the most straightforward way, -you only really need to read the Postmodern reference and glance over the -S-SQL reference. The simple-date reference explains the time-related data -types included in Postmodern, and the CL-postgres reference might be useful -if you just want a low-level library for talking to a PostgreSQL server. - -- [[file:postmodern.html][Postmodern]] -- [[file:s-sql.html][S-SQL]] -- [[file:simple-date.html][Simple-date]] -- [[file:cl-postgres.html][CL-postgres]] - -Some specific topics in more detail - -- [[file:array-notes.html][Array-Notes]] -- [[file:create-tables.html][Creating Tables]] -- [[file:dao-classes.html][Database Access Object (Dao) Classes]] -- [[file:dynamic-queries.html][Dynamic Queries]] -- [[file:interval-notes.html][Interval Notes]] -- [[file:isolation-notes.html][Isolation Notes]] - * Data Types :PROPERTIES: :ID: d089d05b-4485-4fb5-9097-5a66492bc470 @@ -755,6 +756,9 @@ Now the s-sql version: "2020-10-30 19:30:54" "19:30:54" "2020-10-30")) #+END_SRC *** Simple-Date Library Use + :PROPERTIES: + :CUSTOM_ID: simple-date-library-use + :END: The Simple-date add-on library (not enabled by default) provides types (CLOS classes) for dates, timestamps, and intervals similar to the ones SQL databases use, in order to be able to store and read @@ -815,6 +819,9 @@ information when using `timestamp with time zone`. Time zone information only used to convert it to proper UTC timestamp. *** Local-Time Library Use + :PROPERTIES: + :CUSTOM_ID: local-time-library-use + :END: For those who want to use local-time, to enable the local-time reader: #+BEGIN_SRC lisp (ql:quickload :cl-postgres+local-time) @@ -902,12 +909,9 @@ words are: :ID: 50d91126-93f1-4f50-96ad-bd63a7278866 :CUSTOM_ID: 4ac8f5f4-d3b0-41c5-a222-fe3086049279 :END: -Postmodern is under active development so Issues and feature requests should +Postmodern is under active maintenance so issues and feature requests should be flagged on [[https://github.com/marijnh/Postmodern][Postmodern's site on github]]. -Some areas that are currently under consideration can be found in the ROADMAP.md -file. - * Resources :PROPERTIES: :ID: eb969965-5221-48f8-bb79-5a93fe451454 diff --git a/doc/intro-to-s-sql.html b/doc/intro-to-s-sql.html new file mode 100644 index 0000000..47c8c62 --- /dev/null +++ b/doc/intro-to-s-sql.html @@ -0,0 +1,995 @@ + + + + + + +Intro to S-SQL + + + + + + + +
    +
    +

    Intro to S-SQL

    +
    + + + +++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ + + + + + + + + + + + + + + + + + + + + + + + + + + + + +
    ABCDEFGHIJKLMNOPRSTUVWSpecial CharactersCalling Postgresql Stored Functions and Procedures
    + +
    +

    Intro to S-SQL

    +
    +

    +Postmodern can use any sql string in a query. It also has its own lispy syntax called s-sql. Various examples using postmodern will be given in both standard sql and s-sql. Note that not all of sql has been implemented in the s-sql syntax. Postmodern is fully capable of handling any sql string. It just looks a little ugly once you get used to looking at lisp type syntax. +

    + +

    +Consider the following database calls and the return. Note that all query functions are postmodern functions, after this next example, I'm going to shorten the function call and drop the "postmodern:". +

    +
    +
    (postmodern:query "select id, name from countries where name=$1" "Vietnam")
    +
    +((68 "Vietnam"))
    +
    +
    +
    + +

    +This can be rephrased in s-sql as: +

    +
    +
    (query (:select 'id 'name
    +                :from 'countries
    +                :where (:= 'name '$1))
    +
    +        "Vietnam")
    +
    +
    +
    + +

    +You will notice that the commas have dropped out, columns and table names are inital-quoted and the sql operators have colons in from. It does look more "lispy" doesn't it? +

    + +

    +It can be handy to note that replacing "query" with "sql" returns the sql statement rather than trying to execute the query. This can be helpful in designing s-sql queries. Thus: +

    +
    +
    (sql (:select 'countries.name 'regions.name :distinct
    +              :from 'regions 'countries
    +              :where (:= 'regions.id 'countries.region_id)))
    +
    + "(SELECT DISTINCT countries.name, regions.name FROM regions, countries WHERE (regions.id = countries.region_id))"
    +
    +
    +
    +
    +
    + +
    +

    Sql-escape, Sql-escape-string

    +
    +

    +Does what it says on the tin. It escapes a string so that you can safely include the string in an sql query. +

    +
    +
    (let ((x "\#udlsh29c#^"))
    +   (sql-escape x))
    +
    +"E'#udlsh29c#^'"
    +
    +(sql-escape-string "\#udlsh29c#^")
    +
    +"E'#udlsh29c#^'"
    +
    +
    +
    +
    +
    + +
    +

    Sql-compile

    +
    +

    +sql-compile is the run-time version of the sql macro, which means that it converts a list into an sql query. See the following as an example. Note carefully the backquotes and commas. +

    +
    +
    (defun create-table1 (table-name-string &rest rest)
    +  "Each of the parameters after the table-name must be in the form ofa two parameter list - the column name as a string and the type as a symbol. See the following as an example"
    +  (query (postmodern:sql-compile
    +          `(:create-table ,table-name-string ,(loop for y in rest collect
    +                                                    (list (first y)
    +                                                          :type (second y)))))))
    +
    +(create-table1 "test25" (list "name" 'string) (list "address" 'string))
    +
    +
    +
    + +

    +You also can see how it is used in the following queries handling some insertions and updates in which plists were providing the source of columns and values. +

    +
    +
    (query
    + (sql-compile
    +  (append `(:insert-into ,table :set) plst)))
    +
    +(query
    + (sql-compile
    +  (append (append `(:update ,table :set)
    +                  plst)
    +          `(:where (:= 'id ,id)))))
    +
    +
    +
    + + +

    +Remember, if you are using sql-compile or any other method to create dynamic queries, you are responsible for ensuring the security. All user input should be sanitized. +

    +
    +
    +
    +

    Return Types

    +
    +

    +You can give postmodern various directions, using keywords, for way that values get returned. Some of these keywords will be used in various examples to follow. +

    + + + + + +++ ++ + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + +
    :noneIgnore the result values.
    :lists, :rowsReturn a list of lists, each list containing the values for a row.
    :list, :rowReturn a single row as a list.
    :alistsReturn a list of alists which map column names to values, with the names represented as keywords.
    :alistReturn a single row as an alist.
    :str-alistsLike :alists, but use the original column names.
    :str-alistReturn a single row as an alist, with strings for names.
    :plistsReturn a list of plists which map column names to values,with the names represented as keywords.
    :plistReturn a single row as a plist.
    :columnReturn a single column as a list.
    :singleReturn a single value. Will raise an error if the query returns more than one field. If the query returns more than one row, it returns the first row.
    :single!Like :single except that it will throw an error when the number of selected rows is not equal to 1.
    :vectorsReturn a vector of vectors, each vector containing the values for a row. (This is only the plural)
    :array-hashReturn an array of hashtables which map column names to hash table keys
    :json-strsReturn a list of strings where each row is a json object expressed as a string
    :json-strReturn a single string where the row returned is a json object expressed as a string
    :json-array-strReturn a string containing a json array, each element in the array is a selected row expressed as a json object
    (:dao type)Return a list of DAOs of the given type. The names of the fields returned by the query must match slots in the DAO class the same way as with query-dao.
    (:dao type :single)Return a single DAO of the given type.
    + +

    +Consider the following database calls, written in s-sql and the return, noting how the ending keywords affect the type of return: +

    +
    +
    (query (:select 'name
    +        :from 'countries
    +        :where (:> 'latitude '$1))
    +       60)
    +
    +(("Faroe Islands") ("Finland") ("Greenland") ("Iceland") ("Norway") ("Sweden"))
    +
    +
    +
    +
    + +
    +

    :none

    +
    +
    +
    (query (:select 'name
    +                :from 'countries
    +                :where (:> 'latitude '$1))
    +       60 :none)
    +
    +NIL
    +
    +
    +
    +
    + +
    +

    :lists

    +
    +

    +Return a list of lists, each list containing the values for a row. +

    +
    +
    (query (:select 'name
    +                :from 'countries
    +                :where (:> 'latitude '$1))
    +       60 :lists)
    +
    +(("Faroe Islands") ("Iceland") ("Greenland") ("Sweden") ("Norway") ("Finland"))
    +
    +
    +
    +
    +
    + +
    +

    :rows

    +
    +

    +Same as lists - Return a list of lists, each list containing the values for a row. +

    +
    +
    (query (:select 'name
    +                :from 'countries
    +                :where (:> 'latitude '$1))
    +       60 :rows)
    +
    +(("Faroe Islands") ("Iceland") ("Greenland") ("Sweden") ("Norway") ("Finland"))
    +
    +
    +
    +
    +
    + +
    +

    :alist

    +
    +
    +
    (query (:select 'name
    +                :from 'countries
    +                :where (:> 'latitude '$1))
    +       60 :alist)
    +
    +((:NAME . "Faroe Islands"))
    +
    +
    +
    +
    + + +
    +

    :str-alist

    +
    +
    +
    (query (:select 'name
    +                :from 'countries
    +                :where (:> 'latitude '$1))
    +       60 :str-alist)
    +
    +(("name" . "Faroe Islands"))
    +
    +
    +
    +
    +
    + +
    +

    :alists

    +
    +
    +
    (query (:select 'name
    +                :from 'countries
    +                :where (:> 'latitude '$1))
    +       60 :alists)
    +
    +(((:NAME . "Faroe Islands")) ((:NAME . "Finland")) ((:NAME . "Greenland"))  ((:NAME . "Iceland")) ((:NAME . "Norway")) ((:NAME . "Sweden")))
    +
    +
    +
    +
    +
    + +
    +

    :str-alists

    +
    +
    +
    (query (:select 'name
    +                :from 'countries
    +                :where (:> 'latitude '$1))
    +       60 :str-alists)
    +
    +((("name" . "Faroe Islands")) (("name" . "Finland")) (("name" . "Greenland"))  (("name" . "Iceland")) (("name" . "Norway")) (("name" . "Sweden")))
    +
    +
    +
    +
    +
    + +
    +

    :plist

    +
    +
    +
    (query (:select 'name
    +                :from 'countries
    +                :where (:> 'latitude '$1))
    +       60 :plist)
    +
    +(:NAME "Faroe Islands")
    +
    +
    +
    +
    +
    + +
    +

    :plists

    +
    +
    +
    (query (:select 'name
    +                :from 'countries
    +                :where (:> 'latitude '$1))
    +       60 :plists)
    +
    +((:NAME "Faroe Islands") (:NAME "Iceland") (:NAME "Greenland")  (:NAME "Sweden") (:NAME "Norway") (:NAME "Finland"))
    +
    +
    +
    +
    +
    + +
    +

    :array-hash

    +
    +
    +
    (query (:select 'name
    +                :from 'countries
    +                :where (:> 'latitude '$1))
    +       60 :array-hash)
    +
    +#(#<HASH-TABLE :TEST EQUAL :COUNT 1 {1005DFB5A3}>   #<HASH-TABLE :TEST EQUAL :COUNT 1 {1005DFBB63}>   #<HASH-TABLE :TEST EQUAL :COUNT 1 {1005DFC123}>   #<HASH-TABLE :TEST EQUAL :COUNT 1 {1005DFC6E3}>   #<HASH-TABLE :TEST EQUAL :COUNT 1 {1005DFCCA3}>   #<HASH-TABLE :TEST EQUAL :COUNT 1 {1005DFD263}>   #<HASH-TABLE :TEST EQUAL :COUNT 1 {1005DFD823}>   #<HASH-TABLE :TEST EQUAL :COUNT 1 {1005DFDDE3}>   #<HASH-TABLE :TEST EQUAL :COUNT 1 {1005DFE3A3}>)
    +
    +
    +
    +
    +
    + +
    +

    :single

    +
    +

    +Returns a single value. Will raise an error if the query returns more than one field. If the query returns more than one row, it returns the first row. +

    +
    +
    (query (:select 'name
    +                :from 'countries
    +                :where (:> 'latitude '$1))
    +       60 :single)
    +
    +"Faroe Islands"
    +
    +
    +
    +
    +
    + +
    +

    :single!

    +
    +

    +Like :single except that it will throw an error when the number of selected rows is not equal to 1. +

    +
    +
    (query (:select 'name
    +                :from 'countries
    +                :where (:> 'latitude '$1))
    +       60 :single!)
    +
    +; Evaluation aborted on #<CL-POSTGRES:DATABASE-ERROR {100E83B813}>. LISP-TAX-TEST> Database error: Query for a single row returned 6 rows.    [Condition of type DATABASE-ERROR]
    +
    +
    +
    +
    +
    + +
    +

    :column

    +
    +

    +:PROPERTIES: +:CUSTOM_ID: return-type-column +:END +Returns a single column as a list. The first example shows the default value returned without the :column qualifier. The second example shows the result with the column qualifier. : +

    +
    +
    (query (:select 'name
    +
    +                :from 'countries
    +
    +                :where (:> 'latitude '$1))
    +
    +       60 :column)
    +
    +("Faroe Islands" "Finland" "Greenland" "Iceland" "Norway" "Sweden")
    +
    +
    +
    +
    +
    +

    :vectors

    +
    +

    +:PROPERTIES: +:CUSTOM_ID: return-type-vector +:END +

    +
    +
    (query (:select 'id 'int4 'text :from 'test-data)
    +       :vectors)
    +#(#(1 2147483645 "text one")
    +  #(2 0 "text two")
    +  #(3 3 "text three"))
    +
    +(query (:select 'id 'int4 'text :from 'test-data :where (:< 'id 1))
    +       :vectors)
    +#()
    +
    +
    +
    +
    +
    +

    (:dao dao-type)

    +
    +

    +This assumes you have already created a class for this table. +

    +
    +
    (query (:select '* :from 'countries)
    +       (:dao country))
    +
    +(#<COUNTRY {1004F1BAF3}> #<COUNTRY {1004F1BD73}> #<COUNTRY {1004F1BFF3}>)
    +
    +
    +
    +
    +
    + +
    +

    (:dao dao-type :single)

    +
    +
    +
    (query (:select '* :from 'countries :where (:= 'name "Iceland")
    +       (:dao country))
    +
    +#<COUNTRY {1004F1BAF3}>
    +
    +
    +
    +
    +
    + +
    +

    Json-strs

    +
    +

    +Return a list of strings where the row returned is a json object expressed as a string +

    +
    +
    (query (:select 'id 'int4 'text :from 'short-data-type-tests :where (:< 'id 3)) :json-strs)
    +("{\"id\":1,\"int4\":2147483645,\"text\":\"text one\"}"
    + "{\"id\":2,\"int4\":0,\"text\":\"text two\"}")
    +
    +
    +
    + +

    +This will also handle local-time timestamps and simple-date timestamps, time-of-day and date. E.g. (with a local-time timestamp) +

    +
    +
    (query (:select 'timestamp-with-time-zone
    +        :from 'test-data
    +        :where (:< 'id 3))
    +       :json-strs)
    +
    +'("{\"timestampWithTimeZone\":\"{2019-12-30T13:30:54.000000-05:00}\"}"
    +  "{\"timestampWithTimeZone\":\"{1919-12-30T13:30:54.000000-05:00}\"}")
    +
    +
    +
    + +

    +The following is an example with a simple-date timestamp. +

    +
    +
    (query (:select 'timestamp-with-time-zone
    +        :from 'test-data
    +        :where (:< 'id 3)) :json-strs)
    +'("{\"timestampWithTimeZone\":\"2019-12-30 18:30:54:0\"}"
    +  "{\"timestampWithTimeZone\":\"1919-12-30 18:30:54:0\"}")
    +
    +
    +
    +
    +
    + +
    +

    Json-str

    +
    +

    +Return a single string where the row returned is a json object expressed as a string +

    +
    +
    (query (:select 'id 'int4 'text :from 'short-data-type-tests :where (:= 'id 3)) :json-str)
    +"{\"id\":3,\"int4\":3,\"text\":\"text three\"}"
    +
    +
    +
    + +

    +As with :json-strs, this will also work for either simple-date or local-time timestamps +

    +
    +
    +
    +

    Json-array-str

    +
    +

    +Return a string containing a json array, each element in the array is a selected row expressed as a json object. NOTE: If there is no result, this will return a string with an empty json array. +

    +
    +
    (query (:select 'id 'int4 'text :from 'short-data-type-tests :where (:< 'id 3)) :json-array-str)
    +"[{\"id\":1,\"int4\":2147483645,\"text\":\"text one\"}, {\"id\":2,\"int4\":0,\"text\":\"text two\"}]"
    +
    +(query (:select 'id 'int4 'text :from 'test-data :where (:< 'id 1)) :json-array-str)
    +"[]"
    +
    +
    +
    + +

    +As with :json-strs, this will also work for either simple-date or local-time timestamps +

    +
    +
    +
    + +
    +

    As or Alias

    +
    +

    +Suppose you want to return an identifier as a key with the value, but you don't want to use the column name. You can use the as keyword, or as you would expect having just seen a little s-sql, the :as keyword. +

    +
    +
    (first (query (:order-by
    +               (:select (:as 'countries.name 'countryname)
    +                        :from 'countries)
    +               'countryname )
    +              :alists))
    +
    +((:COUNTRYNAME . "Afghanistan"))
    +
    +
    +
    + +

    +You can also do this with table names. +

    +
    +
    (first (query (:order-by
    +               (:select 't1.name
    +                        :from (:as 'countries 't1))
    +               'name )
    +              :alists))
    +
    +((:NAME . "Afghanistan"))
    +
    +
    +
    +
    + +
    +

    :|| Concatenating Columns

    +
    +

    +The concatenation operator combines two or more columns into a single column return. First, consider the query on a raw sql string: +

    +
    +
    (query "(SELECT countries.id, (countries.name || '-' || regions.name)
    +         FROM countries, regions
    +         WHERE ((regions.id = countries.region_id) and (countries.name = 'US')))")
    +
    +((21 "US-North America"))
    +
    +
    +
    + +

    +Now consider the result using s-sql. +

    +
    +
    (query (:select 'countries.id (:|| 'countries.name "-" 'regions.name)
    +                :from 'countries 'regions
    +                :where (:and (:= 'regions.id 'countries.region-id)
    +                             (:= 'countries.name "US"))))
    +
    +((21 "US-North America"))
    +
    +
    +
    +
    +
    +
    +
    + + \ No newline at end of file diff --git a/doc/intro-to-s-sql.org b/doc/intro-to-s-sql.org new file mode 100644 index 0000000..82af276 --- /dev/null +++ b/doc/intro-to-s-sql.org @@ -0,0 +1,468 @@ +#+TITLE: Intro to S-SQL +#+OPTIONS: num:nil +#+HTML_HEAD: +#+HTML_HEAD: +#+OPTIONS: ^:nil + +| [[file:s-sql-a.org][A]]| [[file:s-sql-b.org][B]]| [[file:s-sql-c.org][C]]| [[file:s-sql-d.org][D]]| [[file:s-sql-e.org][E]]| [[file:s-sql-f.org][F]]| [[file:s-sql-g.org][G]]| [[file:s-sql-h.org][H]]| [[file:s-sql-i.org][I]]| [[file:s-sql-j.org][J]]| [[file:s-sql-k.org][K]]| [[file:s-sql-l.org][L]]| [[file:s-sql-m.org][M]]| [[file:s-sql-n.org][N]]| [[file:s-sql-o.org][O]]| [[file:s-sql-p.org][P]]| [[file:s-sql-r.org][R]]| [[file:s-sql-s.org][S]]| [[file:s-sql-t.org][T]]| [[file:s-sql-u.org][U]]| [[file:s-sql-v.org][V]]| [[file:s-sql-w.org][W]]| [[file:s-sql-special-characters.org][Special Characters]] | [[file:calling-postgresql-stored-functions.org][Calling Postgresql Stored Functions and Procedures]]| + +* Intro to S-SQL + :PROPERTIES: + :CUSTOM_ID: intro + :END: +Postmodern can use any sql string in a query. It also has its own lispy syntax called s-sql. Various examples using postmodern will be given in both standard sql and s-sql. Note that not all of sql has been implemented in the s-sql syntax. Postmodern is fully capable of handling any sql string. It just looks a little ugly once you get used to looking at lisp type syntax. + +Consider the following database calls and the return. Note that all query functions are postmodern functions, after this next example, I'm going to shorten the function call and drop the "postmodern:". +#+begin_src lisp + (postmodern:query "select id, name from countries where name=$1" "Vietnam") + + ((68 "Vietnam")) + +#+end_src + +This can be rephrased in s-sql as: +#+begin_src lisp +(query (:select 'id 'name + :from 'countries + :where (:= 'name '$1)) + + "Vietnam") + +#+end_src + +You will notice that the commas have dropped out, columns and table names are inital-quoted and the sql operators have colons in from. It does look more "lispy" doesn't it? + +It can be handy to note that replacing "query" with "sql" returns the sql statement rather than trying to execute the query. This can be helpful in designing s-sql queries. Thus: +#+begin_src lisp +(sql (:select 'countries.name 'regions.name :distinct + :from 'regions 'countries + :where (:= 'regions.id 'countries.region_id))) + + "(SELECT DISTINCT countries.name, regions.name FROM regions, countries WHERE (regions.id = countries.region_id))" + +#+end_src + +* Sql-escape, Sql-escape-string + :PROPERTIES: + :CUSTOM_ID: sql-escape + :END: +Does what it says on the tin. It escapes a string so that you can safely include the string in an sql query. +#+begin_src lisp +(let ((x "\#udlsh29c#^")) + (sql-escape x)) + +"E'#udlsh29c#^'" + +(sql-escape-string "\#udlsh29c#^") + +"E'#udlsh29c#^'" + +#+end_src + +* Sql-compile + :PROPERTIES: + :CUSTOM_ID: sql-compile + :END: + +sql-compile is the run-time version of the sql macro, which means that it converts a list into an sql query. See the following as an example. Note carefully the backquotes and commas. +#+begin_src lisp +(defun create-table1 (table-name-string &rest rest) + "Each of the parameters after the table-name must be in the form ofa two parameter list - the column name as a string and the type as a symbol. See the following as an example" + (query (postmodern:sql-compile + `(:create-table ,table-name-string ,(loop for y in rest collect + (list (first y) + :type (second y))))))) + +(create-table1 "test25" (list "name" 'string) (list "address" 'string)) + +#+end_src + +You also can see how it is used in the following queries handling some insertions and updates in which plists were providing the source of columns and values. +#+begin_src lisp + (query + (sql-compile + (append `(:insert-into ,table :set) plst))) + + (query + (sql-compile + (append (append `(:update ,table :set) + plst) + `(:where (:= 'id ,id))))) + +#+end_src + + +Remember, if you are using sql-compile or any other method to create dynamic queries, you are responsible for ensuring the security. All user input should be sanitized. +* Return Types + :PROPERTIES: + :CUSTOM_ID: return-types + :END: +You can give postmodern various directions, using keywords, for way that values get returned. Some of these keywords will be used in various examples to follow. + + +| :none | Ignore the result values. | +| :lists, :rows | Return a list of lists, each list containing the values for a row. | +| :list, :row | Return a single row as a list. | +| :alists | Return a list of alists which map column names to values, with the names represented as keywords. | +| :alist | Return a single row as an alist. | +| :str-alists | Like :alists, but use the original column names. | +| :str-alist | Return a single row as an alist, with strings for names. | +| :plists | Return a list of plists which map column names to values,with the names represented as keywords. | +| :plist | Return a single row as a plist. | +| :column | Return a single column as a list. | +| :single | Return a single value. Will raise an error if the query returns more than one field. If the query returns more than one row, it returns the first row. | +| :single! | Like :single except that it will throw an error when the number of selected rows is not equal to 1. | +| :vectors | Return a vector of vectors, each vector containing the values for a row. (This is only the plural) | +| :array-hash | Return an array of hashtables which map column names to hash table keys | +| :json-strs | Return a list of strings where each row is a json object expressed as a string | +| :json-str | Return a single string where the row returned is a json object expressed as a string | +| :json-array-str | Return a string containing a json array, each element in the array is a selected row expressed as a json object | +| (:dao type) | Return a list of DAOs of the given type. The names of the fields returned by the query must match slots in the DAO class the same way as with query-dao. | +| (:dao type :single) | Return a single DAO of the given type. | + +Consider the following database calls, written in s-sql and the return, noting how the ending keywords affect the type of return: +#+begin_src lisp + (query (:select 'name + :from 'countries + :where (:> 'latitude '$1)) + 60) + + (("Faroe Islands") ("Finland") ("Greenland") ("Iceland") ("Norway") ("Sweden")) + +#+end_src + +** :none + :PROPERTIES: + :CUSTOM_ID: return-type-none + :END: +#+begin_src lisp +(query (:select 'name + :from 'countries + :where (:> 'latitude '$1)) + 60 :none) + +NIL +#+end_src + +** :lists + :PROPERTIES: + :CUSTOM_ID: return-type-lists + :END: + Return a list of lists, each list containing the values for a row. +#+begin_src lisp +(query (:select 'name + :from 'countries + :where (:> 'latitude '$1)) + 60 :lists) + +(("Faroe Islands") ("Iceland") ("Greenland") ("Sweden") ("Norway") ("Finland")) + +#+end_src + +** :rows + :PROPERTIES: + :CUSTOM_ID: return-type-rows + :END: + Same as lists - Return a list of lists, each list containing the values for a row. +#+begin_src lisp + (query (:select 'name + :from 'countries + :where (:> 'latitude '$1)) + 60 :rows) + + (("Faroe Islands") ("Iceland") ("Greenland") ("Sweden") ("Norway") ("Finland")) + +#+end_src + +** :alist + :PROPERTIES: + :CUSTOM_ID: return-type-alist + :END: +#+begin_src lisp + (query (:select 'name + :from 'countries + :where (:> 'latitude '$1)) + 60 :alist) + + ((:NAME . "Faroe Islands")) +#+end_src + + +** :str-alist + :PROPERTIES: + :CUSTOM_ID: return-type-str-alist + :END: +#+begin_src lisp +(query (:select 'name + :from 'countries + :where (:> 'latitude '$1)) + 60 :str-alist) + +(("name" . "Faroe Islands")) + +#+end_src + +** :alists + :PROPERTIES: + :CUSTOM_ID: return-type-alists + :END: +#+begin_src lisp +(query (:select 'name + :from 'countries + :where (:> 'latitude '$1)) + 60 :alists) + +(((:NAME . "Faroe Islands")) ((:NAME . "Finland")) ((:NAME . "Greenland")) ((:NAME . "Iceland")) ((:NAME . "Norway")) ((:NAME . "Sweden"))) + +#+end_src + +** :str-alists + :PROPERTIES: + :CUSTOM_ID: return-type-str-alists + :END: +#+begin_src lisp +(query (:select 'name + :from 'countries + :where (:> 'latitude '$1)) + 60 :str-alists) + +((("name" . "Faroe Islands")) (("name" . "Finland")) (("name" . "Greenland")) (("name" . "Iceland")) (("name" . "Norway")) (("name" . "Sweden"))) + +#+end_src + +** :plist + :PROPERTIES: + :CUSTOM_ID: return-type-plist + :END: +#+begin_src lisp +(query (:select 'name + :from 'countries + :where (:> 'latitude '$1)) + 60 :plist) + +(:NAME "Faroe Islands") + +#+end_src + +** :plists + :PROPERTIES: + :CUSTOM_ID: return-type-plists + :END: +#+begin_src lisp +(query (:select 'name + :from 'countries + :where (:> 'latitude '$1)) + 60 :plists) + +((:NAME "Faroe Islands") (:NAME "Iceland") (:NAME "Greenland") (:NAME "Sweden") (:NAME "Norway") (:NAME "Finland")) + +#+end_src + +** :array-hash + :PROPERTIES: + :CUSTOM_ID: return-type-array-hash + :END: +#+begin_src lisp +(query (:select 'name + :from 'countries + :where (:> 'latitude '$1)) + 60 :array-hash) + +#(# # # # # # # # #) + +#+end_src + +** :single + :PROPERTIES: + :CUSTOM_ID: return-type-single + :END: + Returns a single value. Will raise an error if the query returns more than one field. If the query returns more than one row, it returns the first row. +#+begin_src lisp +(query (:select 'name + :from 'countries + :where (:> 'latitude '$1)) + 60 :single) + +"Faroe Islands" + +#+end_src + +** :single! + :PROPERTIES: + :CUSTOM_ID: return-type-single-bang + :END: + Like :single except that it will throw an error when the number of selected rows is not equal to 1. +#+begin_src lisp +(query (:select 'name + :from 'countries + :where (:> 'latitude '$1)) + 60 :single!) + +; Evaluation aborted on #. LISP-TAX-TEST> Database error: Query for a single row returned 6 rows. [Condition of type DATABASE-ERROR] + +#+end_src + +** :column + :PROPERTIES: + :CUSTOM_ID: return-type-column + :END + Returns a single column as a list. The first example shows the default value returned without the :column qualifier. The second example shows the result with the column qualifier. : +#+begin_src lisp +(query (:select 'name + + :from 'countries + + :where (:> 'latitude '$1)) + + 60 :column) + +("Faroe Islands" "Finland" "Greenland" "Iceland" "Norway" "Sweden") +#+end_src +** :vectors + :PROPERTIES: + :CUSTOM_ID: return-type-vector + :END + #+begin_src lisp + (query (:select 'id 'int4 'text :from 'test-data) + :vectors) + #(#(1 2147483645 "text one") + #(2 0 "text two") + #(3 3 "text three")) + + (query (:select 'id 'int4 'text :from 'test-data :where (:< 'id 1)) + :vectors) + #() + #+end_src +** (:dao dao-type) + :PROPERTIES: + :CUSTOM_ID: return-type-dao-type + :END: +This assumes you have already created a class for this table. +#+begin_src lisp + (query (:select '* :from 'countries) + (:dao country)) + + (# # #) + +#+end_src + +** (:dao dao-type :single) + :PROPERTIES: + :CUSTOM_ID: return-type-dao-type-single + :END: +#+begin_src lisp +(query (:select '* :from 'countries :where (:= 'name "Iceland") + (:dao country)) + +# + +#+end_src + +** Json-strs + +Return a list of strings where the row returned is a json object expressed as a string +#+begin_src lisp +(query (:select 'id 'int4 'text :from 'short-data-type-tests :where (:< 'id 3)) :json-strs) +("{\"id\":1,\"int4\":2147483645,\"text\":\"text one\"}" + "{\"id\":2,\"int4\":0,\"text\":\"text two\"}") + +#+end_src + +This will also handle local-time timestamps and simple-date timestamps, time-of-day and date. E.g. (with a local-time timestamp) +#+begin_src lisp +(query (:select 'timestamp-with-time-zone + :from 'test-data + :where (:< 'id 3)) + :json-strs) + +'("{\"timestampWithTimeZone\":\"{2019-12-30T13:30:54.000000-05:00}\"}" + "{\"timestampWithTimeZone\":\"{1919-12-30T13:30:54.000000-05:00}\"}") + +#+end_src + +The following is an example with a simple-date timestamp. +#+begin_src lisp +(query (:select 'timestamp-with-time-zone + :from 'test-data + :where (:< 'id 3)) :json-strs) +'("{\"timestampWithTimeZone\":\"2019-12-30 18:30:54:0\"}" + "{\"timestampWithTimeZone\":\"1919-12-30 18:30:54:0\"}") + +#+end_src + +** Json-str + +Return a single string where the row returned is a json object expressed as a string +#+begin_src lisp +(query (:select 'id 'int4 'text :from 'short-data-type-tests :where (:= 'id 3)) :json-str) +"{\"id\":3,\"int4\":3,\"text\":\"text three\"}" + +#+end_src + +As with :json-strs, this will also work for either simple-date or local-time timestamps +** Json-array-str + +Return a string containing a json array, each element in the array is a selected row expressed as a json object. NOTE: If there is no result, this will return a string with an empty json array. +#+begin_src lisp +(query (:select 'id 'int4 'text :from 'short-data-type-tests :where (:< 'id 3)) :json-array-str) +"[{\"id\":1,\"int4\":2147483645,\"text\":\"text one\"}, {\"id\":2,\"int4\":0,\"text\":\"text two\"}]" + +(query (:select 'id 'int4 'text :from 'test-data :where (:< 'id 1)) :json-array-str) +"[]" + +#+end_src + +As with :json-strs, this will also work for either simple-date or local-time timestamps + +* As or Alias + :PROPERTIES: + :CUSTOM_ID: alias + :END: +Suppose you want to return an identifier as a key with the value, but you don't want to use the column name. You can use the as keyword, or as you would expect having just seen a little s-sql, the :as keyword. +#+begin_src lisp +(first (query (:order-by + (:select (:as 'countries.name 'countryname) + :from 'countries) + 'countryname ) + :alists)) + +((:COUNTRYNAME . "Afghanistan")) + +#+end_src + +You can also do this with table names. +#+begin_src lisp +(first (query (:order-by + (:select 't1.name + :from (:as 'countries 't1)) + 'name ) + :alists)) + +((:NAME . "Afghanistan")) + +#+end_src + +** :|| Concatenating Columns + :PROPERTIES: + :CUSTOM_ID: concatenate + :END: +The concatenation operator combines two or more columns into a single column return. First, consider the query on a raw sql string: +#+begin_src lisp +(query "(SELECT countries.id, (countries.name || '-' || regions.name) + FROM countries, regions + WHERE ((regions.id = countries.region_id) and (countries.name = 'US')))") + +((21 "US-North America")) + +#+end_src + +Now consider the result using s-sql. +#+begin_src lisp +(query (:select 'countries.id (:|| 'countries.name "-" 'regions.name) + :from 'countries 'regions + :where (:and (:= 'regions.id 'countries.region-id) + (:= 'countries.name "US")))) + +((21 "US-North America")) + +#+end_src diff --git a/doc/postmodern.html b/doc/postmodern.html index 728aecf..eb085e5 100644 --- a/doc/postmodern.html +++ b/doc/postmodern.html @@ -1,7 +1,7 @@ - + Postmodern Reference Manual @@ -193,27 +193,38 @@ - + + -
    +
    +

    function load-extension (extension)

    +
    +

    +Loads the Postgresql contrib module or extension provided as a parameter. The parameter provided must be a string. If the extension is not available, Postgresql will throw an error. It will be skipped if it is already loaded. +

    +
    +
    -
    -

    function load-uuid-extension ()

    -
    +
    +

    function load-uuid-extension ()

    +

    Loads the Postgresql uuid-ossp contrib module. Once loaded, you can call uuid generation functions such as uuid_generate_v4 within a query. E.g. @@ -4223,4 +4243,4 @@

    function database-error-extract-na

    - + \ No newline at end of file diff --git a/doc/postmodern.org b/doc/postmodern.org index b150906..617a88a 100644 --- a/doc/postmodern.org +++ b/doc/postmodern.org @@ -1533,10 +1533,16 @@ currently connected database. The extensions may or may not be installed. List the postgresql extensions which are installed in the currently connected database. +** function load-extension (extension) + :PROPERTIES: + :CUSTOM_ID: function-load-extension + :END: + +Loads the Postgresql contrib module or extension provided as a parameter. The parameter provided must be a string. If the extension is not available, Postgresql will throw an error. It will be skipped if it is already loaded. ** function load-uuid-extension () :PROPERTIES: - :CUSTOM_ID: function-load-uuid-extensin + :CUSTOM_ID: function-load-uuid-extension :END: Loads the Postgresql uuid-ossp contrib module. Once loaded, you can call uuid diff --git a/doc/s-sql-a.html b/doc/s-sql-a.html new file mode 100644 index 0000000..29c2357 --- /dev/null +++ b/doc/s-sql-a.html @@ -0,0 +1,552 @@ + + + + + + +S-SQL Examples A + + + + + + + +
    +
    +

    S-SQL Examples A

    +
    + +
    +

    S-SQL Examples Home Page

    +
    + + + +++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ + + + + + + + + + + + + + + + + + + + + + + + + + + + + +
    ABCDEFGHIJKLMNOPRSTUVWSpecial CharactersCalling Postgresql Stored Functions and Procedures
    +
    +
    + +
    +

    And

    +
    +
    +
        (query (:select 'countries.name
    +                  :from 'countries 'regions
    +                  :where (:and (:= 'regions.name "North America")
    +                               (:= 'regions.id 'countries.region-id))))
    +
    +  (("Bermuda") ("Canada") ("Greenland") ("Mexico") ("US"))
    +
    +  (query (:select 'countries.name
    +                  :from 'countries 'regions
    +                  :where (:and (:= 'region-id 'regions.id)
    +                               (:= 'regions.name "Central America")
    +                               (:< 'latitude 12))))
    +
    +(("Costa Rica") ("Panama"))
    +
    +
    +
    +
    + +
    +

    Alter Table

    +
    +
    +
    (query (:alter-table "countries" :add-column "stuff4" :type integer :default 0))
    +
    +(query (:alter-table "countries" :add-column "stuff4" :type integer))
    +
    +(query (:alter-table "countries" :add-column "stuff4" :type (or db-null integer)))
    +
    +
    +
    + +

    +The difference between these versions is how they handle nulls. The first will generate a column that cannot be null and will set a default of 0. The second will not set a default but will still generate a column that cannot be null. The third will not set a default and the column is allowed to be null. Note that because the table name is in double quotes, if you have a multiple word table name, the words must be separated by the normal sql underscores, not the normal "lispy" hyphens. +

    + +

    +You can use sql-compile to build the alter-table statements dynamically like so: +

    +
    +
    (let ((table "countries") (column "stuff4"))
    +  (query (sql-compile `(:alter-table ,table :add-column ,column
    +                        :type (or db-null integer)))))
    +
    +
    +
    +
    + +
    +

    Altering Columns

    +
    +

    +At the moment, altering columns requires that you still include a blank :type keyword. +

    + +

    +As an example, assume you created a table named "test2" with a column named "description" with a not null constraint +

    + +

    +and you want to drop the not null constraint on the table. Either of the following will work +

    + +

    +(the only differences being whether you quote the names or use strings for the names): +

    +
    +
    (query (:alter-table "test2" :alter-column "description" :type (:drop not-null)))
    +
    +(query (:alter-table 'test2 :alter-column 'description :type (:drop not-null)))
    +
    +
    +
    +
    +
    +
    + +
    +

    Any, Any*

    +
    +

    +Any needs to be considered as a special case. Quoting Marijn Haverbeke here,"Postgres has both a function-call-style any and an infix any, and S-SQL's syntax doesn't allow them to be distinguished." As a result, postmodern has a regular :any sql-op and a :any* sql-op, which expand slightly differently. +

    + +

    +In general, the any qualifier in an sql statement looks at a subquery and does a comparison against that subquery. Sticking with our countries table, we have latitude, longitude data for every country (I'm not sure whether my table pulled the capital cities or the geographic center) and some designated a region for each country, so we have a region-id that matches the primary key 'id' in a regions table. +

    + +

    +Out of curiosity, let's determine which countries in "North America" have a longitude less than any country in "South America". The standard sql could look like this: +

    +
    +
      (query "select countries.name
    +               from countries,regions
    +               where regions.id=region_id
    +               and regions.name='North America'
    +               and longitude > any(select longitude
    +                                          from countries, regions
    +                                          where region_id = regions.id
    +                                          and regions.name='South America')")
    +
    +(("Bermuda") ("Greenland"))
    +
    +
    + +

    +This can be re-phrased in s-sql as +

    +
    +
    (query  (:select 'countries.name
    +         :from 'countries 'regions
    +                 :where (:and (:= 'regions.id 'region-id)
    +                              (:= 'regions.name "North America")
    +                              (:> 'longitude
    +                                  (:any
    +                                   (:select 'longitude
    +                                    :from 'countries 'regions
    +                                            :where (:and (:= 'regions.id 'region-id)
    +                                                         (:= 'regions.name
    +                                                             "South America"))))))))
    +
    +(("Bermuda") ("Greenland"))
    +
    +
    + +

    +Subselects work fine in both regular sql and s-sql. If you have already calculated your subselect and put it in a variable, that variable can be a list or a vector and whether you should use the :any sql-op or the :any* sql-op depends on your phrasing. (Notice that the second variation has an asterisk). +

    + +

    +The SQL keyword ANY can be used in a parameterized sql statement. The following two toy examples work in raw sql. +

    +
    +
    (query "select name from countries where id=any($1)"
    +       (vector 21 22))
    +
    +(("Iceland") ("US"))
    +
    +(let ((toy-query (vector 21 22)))
    +  (query "select name from countries where id=any($1)"
    +         toy-query))
    +
    +(("Iceland") ("US"))
    +
    +
    +

    +Now using s-sql and keeping with the toy example, notice that using :any does not work, but using :any* does work. +

    +
    +
    (let ((toy-query '(21 22)))
    +  (query (:select 'name
    +          :from 'countries
    +          :where (:= 'id (:any '$1)))
    +         toy-query))
    +
    +;; Evaluation aborted on #<CL-POSTGRES-ERROR:SYNTAX-ERROR-OR-ACCESS-VIOLATION {10030AF6A1}>.
    +
    +(let ((toy-query '(21 22)))
    +  (query (:select 'name
    +          :from 'countries
    +          :where (:= 'id (:any* '$1)))
    +         toy-query))
    +
    +(("Iceland") ("US"))
    +
    +
    +
    +
    + +
    +

    Arrays - see Array-Notes

    +
    +
    +
    +
    +

    As (sometimes referred to as Alias)

    +
    +
    +
      (query (:select (:as 'countries.name 'country)
    +                (:as 'regions.name 'region)
    +                :from 'countries 'regions
    +                :where (:and (:= 'regions.id 'region-id)
    +                             (:= 'regions.name "Central America")))
    +       :alists)
    +
    +(((:COUNTRY . "Belize") (:REGION . "Central America"))
    + ((:COUNTRY . "Costa Rica")  (:REGION . "Central America"))
    + ((:COUNTRY . "El Salvador")  (:REGION . "Central America"))
    + ((:COUNTRY . "Guatemala")  (:REGION . "Central America"))
    + ((:COUNTRY . "Panama") (:REGION . "Central America"))
    + ((:COUNTRY . "Nicaragua") (:REGION . "Central America")))
    +
    +
    + +

    +The following uses aliases for both columns and tables in the from and inner-join clauses: +

    +
    +
    (query (:order-by
    +      (:select (:as 'recs.firstname 'firstname)
    +               (:as 'recs.surname 'surname)
    +               :distinct
    +               :from (:as 'cd.members 'mems)
    +               :inner-join (:as 'cd.members 'recs)
    +               :on (:= 'recs.memid 'mems.recommendedby))
    +      'surname 'firstname))
    +
    +
    + +

    +Note: Postmodern does not allow you to create an unescaped string alias. In other words, you cannot generate this: +

    +
    +
    "select sum(slots as "Total Slots" from cd.bookings"
    +
    +
    +

    +without using :raw +

    +
    +
    + +
    +

    Avg

    +
    +

    +Simple example easily applicable to max and min: +

    +
    +
    (query (:select (:avg 'longitude)
    +        :from 'countries 'regions
    +                :where (:and (:= 'regions.id 'region-id)
    +                             (:= 'regions.name "North America"))))
    +
    +((-17939/200))
    +
    +
    +
    +
    +
    + + \ No newline at end of file diff --git a/doc/s-sql-a.org b/doc/s-sql-a.org new file mode 100644 index 0000000..dd5d5d6 --- /dev/null +++ b/doc/s-sql-a.org @@ -0,0 +1,199 @@ +#+TITLE: S-SQL Examples A +#+OPTIONS: num:nil +#+HTML_HEAD: +#+HTML_HEAD: +#+OPTIONS: ^:nil + +* [[file:s-sql-examples.org][S-SQL Examples Home Page]] +| [[file:s-sql-a.org][A]]| [[file:s-sql-b.org][B]]| [[file:s-sql-c.org][C]]| [[file:s-sql-d.org][D]]| [[file:s-sql-e.org][E]]| [[file:s-sql-f.org][F]]| [[file:s-sql-g.org][G]]| [[file:s-sql-h.org][H]]| [[file:s-sql-i.org][I]]| [[file:s-sql-j.org][J]]| [[file:s-sql-k.org][K]]| [[file:s-sql-l.org][L]]| [[file:s-sql-m.org][M]]| [[file:s-sql-n.org][N]]| [[file:s-sql-o.org][O]]| [[file:s-sql-p.org][P]]| [[file:s-sql-r.org][R]]| [[file:s-sql-s.org][S]]| [[file:s-sql-t.org][T]]| [[file:s-sql-u.org][U]]| [[file:s-sql-v.org][V]]| [[file:s-sql-w.org][W]]| [[file:s-sql-special-characters.org][Special Characters]] | [[file:calling-postgresql-stored-functions.org][Calling Postgresql Stored Functions and Procedures]]| + +* And + :PROPERTIES: + :CUSTOM_ID: and + :END: +#+begin_src lisp + (query (:select 'countries.name + :from 'countries 'regions + :where (:and (:= 'regions.name "North America") + (:= 'regions.id 'countries.region-id)))) + + (("Bermuda") ("Canada") ("Greenland") ("Mexico") ("US")) + + (query (:select 'countries.name + :from 'countries 'regions + :where (:and (:= 'region-id 'regions.id) + (:= 'regions.name "Central America") + (:< 'latitude 12)))) + + (("Costa Rica") ("Panama")) +#+end_src + +* Alter Table +:PROPERTIES: +:CUSTOM_ID: alter-table +:END: +#+begin_src lisp +(query (:alter-table "countries" :add-column "stuff4" :type integer :default 0)) + +(query (:alter-table "countries" :add-column "stuff4" :type integer)) + +(query (:alter-table "countries" :add-column "stuff4" :type (or db-null integer))) + +#+end_src + +The difference between these versions is how they handle nulls. The first will generate a column that cannot be null and will set a default of 0. The second will not set a default but will still generate a column that cannot be null. The third will not set a default and the column is allowed to be null. Note that because the table name is in double quotes, if you have a multiple word table name, the words must be separated by the normal sql underscores, not the normal "lispy" hyphens. + +You can use sql-compile to build the alter-table statements dynamically like so: +#+begin_src lisp + (let ((table "countries") (column "stuff4")) + (query (sql-compile `(:alter-table ,table :add-column ,column + :type (or db-null integer))))) + +#+end_src + +** Altering Columns +:PROPERTIES: +:CUSTOM_ID: alter-column +:END: +At the moment, altering columns requires that you still include a blank :type keyword. + +As an example, assume you created a table named "test2" with a column named "description" with a not null constraint + +and you want to drop the not null constraint on the table. Either of the following will work + +(the only differences being whether you quote the names or use strings for the names): +#+begin_src lisp +(query (:alter-table "test2" :alter-column "description" :type (:drop not-null))) + +(query (:alter-table 'test2 :alter-column 'description :type (:drop not-null))) + +#+end_src + +* Any, Any* + :PROPERTIES: + :CUSTOM_ID: any + :END: +Any needs to be considered as a special case. Quoting Marijn Haverbeke here,"Postgres has both a function-call-style any and an infix any, and S-SQL's syntax doesn't allow them to be distinguished." As a result, postmodern has a regular :any sql-op and a :any* sql-op, which expand slightly differently. + +In general, the any qualifier in an sql statement looks at a subquery and does a comparison against that subquery. Sticking with our countries table, we have latitude, longitude data for every country (I'm not sure whether my table pulled the capital cities or the geographic center) and some designated a region for each country, so we have a region-id that matches the primary key 'id' in a regions table. + +Out of curiosity, let's determine which countries in "North America" have a longitude less than any country in "South America". The standard sql could look like this: +#+begin_src lisp + (query "select countries.name + from countries,regions + where regions.id=region_id + and regions.name='North America' + and longitude > any(select longitude + from countries, regions + where region_id = regions.id + and regions.name='South America')") + +(("Bermuda") ("Greenland")) +#+end_src + +This can be re-phrased in s-sql as +#+begin_src lisp + (query (:select 'countries.name + :from 'countries 'regions + :where (:and (:= 'regions.id 'region-id) + (:= 'regions.name "North America") + (:> 'longitude + (:any + (:select 'longitude + :from 'countries 'regions + :where (:and (:= 'regions.id 'region-id) + (:= 'regions.name + "South America")))))))) + + (("Bermuda") ("Greenland")) +#+end_src + +Subselects work fine in both regular sql and s-sql. If you have already calculated your subselect and put it in a variable, that variable can be a list or a vector and whether you should use the :any sql-op or the :any* sql-op depends on your phrasing. (Notice that the second variation has an asterisk). + +The SQL keyword ANY can be used in a parameterized sql statement. The following two toy examples work in raw sql. +#+begin_src lisp + (query "select name from countries where id=any($1)" + (vector 21 22)) + + (("Iceland") ("US")) + + (let ((toy-query (vector 21 22))) + (query "select name from countries where id=any($1)" + toy-query)) + + (("Iceland") ("US")) +#+end_src +Now using s-sql and keeping with the toy example, notice that using :any does not work, but using :any* does work. +#+begin_src lisp + (let ((toy-query '(21 22))) + (query (:select 'name + :from 'countries + :where (:= 'id (:any '$1))) + toy-query)) + + ;; Evaluation aborted on #. + + (let ((toy-query '(21 22))) + (query (:select 'name + :from 'countries + :where (:= 'id (:any* '$1))) + toy-query)) + + (("Iceland") ("US")) +#+end_src + +* Arrays - see [[file:array-notes.html][Array-Notes]] + :PROPERTIES: + :CUSTOM_ID: arrays + :END: +* As (sometimes referred to as Alias) + :PROPERTIES: + :CUSTOM_ID: as + :END: +#+begin_src lisp + (query (:select (:as 'countries.name 'country) + (:as 'regions.name 'region) + :from 'countries 'regions + :where (:and (:= 'regions.id 'region-id) + (:= 'regions.name "Central America"))) + :alists) + +(((:COUNTRY . "Belize") (:REGION . "Central America")) + ((:COUNTRY . "Costa Rica") (:REGION . "Central America")) + ((:COUNTRY . "El Salvador") (:REGION . "Central America")) + ((:COUNTRY . "Guatemala") (:REGION . "Central America")) + ((:COUNTRY . "Panama") (:REGION . "Central America")) + ((:COUNTRY . "Nicaragua") (:REGION . "Central America"))) +#+end_src + +The following uses aliases for both columns and tables in the from and inner-join clauses: +#+begin_src lisp + (query (:order-by + (:select (:as 'recs.firstname 'firstname) + (:as 'recs.surname 'surname) + :distinct + :from (:as 'cd.members 'mems) + :inner-join (:as 'cd.members 'recs) + :on (:= 'recs.memid 'mems.recommendedby)) + 'surname 'firstname)) +#+end_src + +Note: Postmodern does not allow you to create an unescaped string alias. In other words, you cannot generate this: +#+begin_src lisp +"select sum(slots as "Total Slots" from cd.bookings" +#+end_src +without using :raw + +* Avg + :PROPERTIES: + :CUSTOM_ID: avg + :END: +Simple example easily applicable to max and min: +#+begin_src lisp + (query (:select (:avg 'longitude) + :from 'countries 'regions + :where (:and (:= 'regions.id 'region-id) + (:= 'regions.name "North America")))) + + ((-17939/200)) + #+end_src diff --git a/doc/s-sql-b.html b/doc/s-sql-b.html new file mode 100644 index 0000000..f009963 --- /dev/null +++ b/doc/s-sql-b.html @@ -0,0 +1,358 @@ + + + + + + +S-SQL Examples B + + + + + + + +
    +
    +

    S-SQL Examples B

    +
    + +
    +

    S-SQL Examples Home Page

    +
    + + + +++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ + + + + + + + + + + + + + + + + + + + + + + + + + + + + +
    ABCDEFGHIJKLMNOPRSTUVWSpecial CharactersCalling Postgresql Stored Functions and Procedures
    +
    +
    + + +
    +

    Between

    +
    +
    +
      (query (:select 'name
    +                :from 'countries
    +                :where (:between 'latitude -10 10))
    +       :column)
    +
    +("Solomon Islands" "Benin" "Brazil" "Brunei" "Cameroon" "Congo"  "Costa Rica" "Ecuador" "Ethiopia" "Gabon" "Ghana"  "Guyana" "Indonesia" "Ivory Coast" "Kenya" "Kiribati" "Liberia"  "Malaysia" "Maldives" "Marshall Islands" "Micronesia" "Nauru" "Nigeria"  "Palau" "Panama" "Papua New Guinea" "Peru" "Rwanda" "Seychelles"  "Sierra Leone" "Singapore" "None" "Sri Lanka" "Suriname" "Tanzania"  "East Timor" "Togo" "Tuvalu" "Uganda" "Venezuela" "Colombia")
    +
    +
    +
    +
    + +
    +

    Boolean Operators (:is-true, :is-false, :is-null)

    +
    +
    +
    +

    :Is-True

    +
    +
    +
    (query (:select '* :from 'boolean-test :where (:is-true 'a)))
    +
    +
    +
    +
    +
    +

    :Is-False

    +
    +
    +
    (sql (:select '* :from 'table1 :where (:is-false 'col)))
    +
    +
    +
    +
    +

    :Is-NULL

    +
    +
    +
    (:select '* :from 'table1 :where (:is-false 'col))
    +
    +
    +
    +
    +
    +
    +
    + + \ No newline at end of file diff --git a/doc/s-sql-b.org b/doc/s-sql-b.org new file mode 100644 index 0000000..adcae61 --- /dev/null +++ b/doc/s-sql-b.org @@ -0,0 +1,39 @@ +#+TITLE: S-SQL Examples B +#+OPTIONS: num:nil +#+HTML_HEAD: +#+HTML_HEAD: +#+OPTIONS: ^:nil + +* [[file:s-sql-examples.org][S-SQL Examples Home Page]] +| [[file:s-sql-a.org][A]]| [[file:s-sql-b.org][B]]| [[file:s-sql-c.org][C]]| [[file:s-sql-d.org][D]]| [[file:s-sql-e.org][E]]| [[file:s-sql-f.org][F]]| [[file:s-sql-g.org][G]]| [[file:s-sql-h.org][H]]| [[file:s-sql-i.org][I]]| [[file:s-sql-j.org][J]]| [[file:s-sql-k.org][K]]| [[file:s-sql-l.org][L]]| [[file:s-sql-m.org][M]]| [[file:s-sql-n.org][N]]| [[file:s-sql-o.org][O]]| [[file:s-sql-p.org][P]]| [[file:s-sql-r.org][R]]| [[file:s-sql-s.org][S]]| [[file:s-sql-t.org][T]]| [[file:s-sql-u.org][U]]| [[file:s-sql-v.org][V]]| [[file:s-sql-w.org][W]]| [[file:s-sql-special-characters.org][Special Characters]] | [[file:calling-postgresql-stored-functions.org][Calling Postgresql Stored Functions and Procedures]]| + + +* Between + :PROPERTIES: + :CUSTOM_ID: between + :END: +#+begin_src lisp + (query (:select 'name + :from 'countries + :where (:between 'latitude -10 10)) + :column) + +("Solomon Islands" "Benin" "Brazil" "Brunei" "Cameroon" "Congo" "Costa Rica" "Ecuador" "Ethiopia" "Gabon" "Ghana" "Guyana" "Indonesia" "Ivory Coast" "Kenya" "Kiribati" "Liberia" "Malaysia" "Maldives" "Marshall Islands" "Micronesia" "Nauru" "Nigeria" "Palau" "Panama" "Papua New Guinea" "Peru" "Rwanda" "Seychelles" "Sierra Leone" "Singapore" "None" "Sri Lanka" "Suriname" "Tanzania" "East Timor" "Togo" "Tuvalu" "Uganda" "Venezuela" "Colombia") +#+end_src + +* Boolean Operators (:is-true, :is-false, :is-null) + :PROPERTIES: + :CUSTOM_ID: boolean + :END: +** :Is-True +#+begin_src lisp + (query (:select '* :from 'boolean-test :where (:is-true 'a))) +#+end_src +** :Is-False +#+begin_src lisp + (sql (:select '* :from 'table1 :where (:is-false 'col))) +#+end_src +*** :Is-NULL +#+begin_src lisp + (:select '* :from 'table1 :where (:is-false 'col)) +#+end_src diff --git a/doc/s-sql-c.html b/doc/s-sql-c.html new file mode 100644 index 0000000..5147b82 --- /dev/null +++ b/doc/s-sql-c.html @@ -0,0 +1,1230 @@ + + + + + + +S-SQL Examples C + + + + + + + +
    +
    +

    S-SQL Examples C

    +
    + +
    +

    S-SQL Examples Home Page

    +
    + + + +++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ + + + + + + + + + + + + + + + + + + + + + + + + + + + + +
    ABCDEFGHIJKLMNOPRSTUVWSpecial CharactersCalling Postgresql Stored Functions and Procedures
    +
    +
    + +
    +

    Call

    +
    +

    +Call is used to call a Postgresql Procedure. This cannot be used in a select clause. You can pass variables to the operator. +

    +
    +
    (query (:call 'set_x_procedure 1 13))
    +
    +(let ((a 1) (b 2))
    +  (query (:call 'my-proc a b 3)))
    +
    +(let ((a 1) (b 2) (p 'my-proc))
    +  (query (:call p a b 3)))
    +
    +
    +
    +
    +
    +

    Case

    +
    +

    +As you know, case is a conditional expression that you can use to either search for rows in a table when a condition is true or compare a table field to a statement in the case expression. So consider the following where you only look at the first 10 rows in the countries table. The Case expression indicates that if the id is less than five, return the word "Low" and if the id is greater than five, return the word "high". Notice what happens when Denmark, with an id of exactly five, gets returned. +

    +
    +
      (query (:select 'id 'name
    +                (:case
    +                 ((:< 'id 5) "Low")
    +                 ((:> 'id 5) "High"))
    +                :from 'countries
    +                :where (:< 'id 10))))
    +
    +((1 "Austria" "Low") (2 "Belgium" "Low") (4 "Canada" "Low") (5 "Denmark" :NULL)
    + (8 "France" "High") (9 "Germany" "High") (7 "Finland" "High"))
    +
    +
    +
    +
    +
    + +
    +

    Cast

    +
    +

    +There are two ways to cast in postmodern. First is the explicit use of cast as in: +

    +
    +
    (query (:select (:cast (:as "2018-04-19" 'date)) :from 'roadmap))
    +
    +
    + +

    +Then there is the use of the type operator which effectively translates into postgresql's :: casting shortcut. +

    +
    +
    (query (:select (:type "2018-04-19" date) :from 'roadmap))
    +
    +
    + +

    +Note that the targetted data type is quoted in the explicit use of cast and not quoted when using type. +

    +
    +
    + +
    +

    Coalesce

    +
    +

    +The COALESCE function in SQL returns the first non-NULL expression among its arguments. +

    +
    +
    (query
    + (:order-by
    +  (:select (:as 'countries.name  'country)
    +           (:as (:coalesce 'countries.latitude  999)
    +                'latitude)
    +           (:as (:coalesce 'countries.longitude 999)
    +                'longitude)
    +   :from 'countries
    +   :where (:and (:> 'countries.name '$1)
    +                (:< 'countries.name '$2)))
    +  'country)
    + "D" "F")
    +
    +(("Denmark" 56 10) ("Dominican Republic" 19 -352/5) ("EU" 999 999)
    +                   ("East Timor" -17/2 2511/20)
    +                   ("Ecuador" -2 -773/10) ("Egypt" 27 30)  ("El Salvador" 27/2 -1771/20) ("Estonia" 59 26) ("Ethiopia" 8 38))
    +
    +
    +
    +
    + +
    +

    Constraints Examples

    +
    +

    +Suppose you want to find the constraints on a particular table. You try something like this: +

    +
    +
      (query (:select '*
    +                :from 'information-schema.table-constraints
    +                :where (:= 'table-name "countries")))
    +
    +(("mydatabase" "public" "countries_pkey" "mydatabase" "public" "countries" "PRIMARY KEY" "NO" "NO")
    +
    + ("mydatabase" "public" "country_name_uk" "mydatabase" "public" "countries" "UNIQUE" "NO" "NO")
    +
    + ("mydatabase" "public" "country_name_unique" "mydatabase" "public" "countries" "UNIQUE" "NO" "NO")
    +
    + ("mydatabase" "public" "2200_456618_1_not_null" "mydatabase" "public" "countries" "CHECK" "NO" "NO"))
    +
    +
    +
    + +

    +Okay. That looks like it works. At a minimum, it is telling me that the countries table has a primary key named "countries_pkey". Also, for some strange reason, it has two unique constraints named "country_name_uk" and "country_name_unique". +

    + +

    +However consider table names with multiple words separated by underscores. If you are used to postmodern turning everything nicely into hyphens, you might try something like: +

    +
    +
    (query (:select '* :from 'information-schema.table-constraints
    +                 :where (:= 'table-name "countries-hyphenated-for-some-reason")))
    +
    +
    +
    + +

    +That will not work. Remember that you have to provide the actual string name of the table. Because sql does not like hyphens and demands underscores, the correct query in postmodern would look like this: +

    +
    +
    (query (:select '* :from 'information-schema.table-constraints
    +        :where (:= 'table-name "countries_hyphenated_for_some_reason")))
    +
    +
    +
    + +

    +Or you could use s-sql:to-sql-name like this: +

    +
    +
    (query (:select '*
    +              :from 'information-schema.table-constraints
    +              :where (:= 'table-name '$1))
    +     (s-sql:to-sql-name 'tasks-lists))
    +
    +
    +
    + +

    +The query in this function generates information on the foreign key constraints in a database. Ignoring all the postgresql internal table names, while this looks complicated, the only additional items really here are :[] as the op for getting an array index, :generate-series, and :array-upper +

    +
    +
    (defun describe-foreign-key-constraints ()
    +  "Generates a list of lists of information on the foreign key constraints"
    +  (query (:order-by (:select 'conname
    +                             (:as 'conrelid 'table)
    +                             (:as 'pgc.relname 'tabname)
    +                             (:as 'a.attname 'columns)
    +                             (:as 'confrelid 'foreign-table)
    +                             (:as 'pgf.relname 'ftabname)
    +                             (:as 'af.attname 'fcolumn)
    +                             :from
    +                             (:as 'pg_attribute 'af)
    +                             (:as 'pg_attribute 'a)
    +                             (:as 'pg_class 'pgc)
    +                             (:as 'pg_class 'pgf)
    +                             (:as
    +                              (:select 'conname 'conrelid 'confrelid
    +                                       (:as (:[] 'conkey 'i) 'conkey)
    +                                       (:as (:[] 'confkey 'i) 'confkey)
    +                                       :from (:as (:select 'conname
    +                                                           'conrelid 'confrelid
    +                                                           'conkey 'confkey
    +                                                           (:as
    +                                                            (:generate-series '1
    +                                                             :array-upper 'conkey 1))
    +                                                           'i)
    +                                              :from 'pg_constraint
    +                                              :where (:= 'contype "f" ))
    +                                       'ss))
    +                             'ss2)
    +          :where (:and (:= 'af.attnum 'confkey)
    +                       (:= 'af.attrelid 'confrelid)
    +                       (:= 'a.attnum 'conkey)
    +                       (:= 'a.attrelid 'conrelid)
    +                       (:= 'pgf.relfilenode 'confrelid)
    +                       (:= 'pgc.relfilenode 'conrelid)))
    +         'ftabname 'fcolumn 'tabname 'columns))
    +
    +
    +
    +
    +
    + +
    +

    Count

    +
    +

    +The simplest use of count looks like this: +

    +
    +
      (query (:select (:count '*) :from 'countries) :single)
    +
    +202
    +
    +
    +
    +
    + +
    +

    Create-Composite-Types

    +
    +

    +Composite types can be created with the :create-composite-type operator. For example: +

    +
    +
    (query (:create-composite-type 'inventory-item
    +                               (name string)
    +                               (df double-float)
    +                               (count bigint)))
    +
    +(query (:create-composite-type 'employee-type (name text) (salary numeric)))
    +
    +
    +

    +Those types can then be used in :create-table queries. +

    +
    +
    (query (:create-table 'distributors
    +                      ((i :type inventory-item)
    +                       (e  :type employee-type))))
    +
    +
    +
    +
    + +
    +

    Create-Index

    +
    +

    +** Basic +

    +

    +:CUSTOM_ID: create-index-basic +

    +

    +To create a B-tree index on the column title in the table films. +

    +
    +
    (query (:create-index 'films_idx :on "films" :fields 'title))
    +
    +
    +
    +
    +

    Multiple Columns

    +
    +

    +Multiple-column indexes: +

    +
    +
    (query (:create-index 'films-idx :on "films" :fields 'title 'id))
    +
    +
    +
    +
    +
    +

    Using Postgresql Expressions

    +
    +

    +To create an index on the postgresql expression lower so as to generate efficient case insensitive searches +

    +
    +
    (query (:create-index 'films_idx :on "films" :fields (:lower 'title)))
    +
    +
    +
    +
    +
    +

    GIN, GIST and other non-B-tree indexes

    +
    +

    +To create an index using e.g. GIN instead of a B-tree index, you need to provide a :using clause: +

    +
    +
    (query (:create-index 'films_idx :on "films" :using 'gin :fields 'title))
    +
    +
    +
    +
    + +
    +

    Indexes with opclass parameters

    +
    +

    +The following basic opclass parameters are supported: +:asc, :desc, :nulls-first, :null-last, :nulls-distinct, :nulls-not-distinct, :array-ops, jsonb-ops, :jsonb-path-ops, :gin-trgm-ops, :tsvector-ops. +

    + +

    +To specify using an opclass parameter, you will need to enclose the specific field in its own form and use a keyword parameter. The second example shows a second field included in the index, but without an opclass parameter, so it does not need to be in its own form (although it can be): +

    +
    +
    (query (:create-index 'items-idx :on 'test-items :using 'gin
    +                 :fields (:jsonb-path-ops 'metadata)))
    +
    +(query (:create-index 'films-idx :on 'films :using 'gin
    +        :fields (:nulls-first 'customer-id ) 'order-date))
    +
    +(query (:create-index 'films-idx :on 'films :using 'gin
    +        :fields (:nulls-first 'customer-id ) (:asc 'order-date)))
    +
    +
    +
    +
    +

    To-Tsvector

    +
    +

    +to-tsvector is a bit of a special case: +

    +
    +
    (query (:create-index 'pgweb-idx :on 'pgweb :using 'gin
    +         :fields (:to-tsvector "english" 'body)))
    +
    +
    +
    +
    +
    +

    2+-ary Operators

    +
    +

    +These operators have two operands. They need to be in their own form: +

    +
    +
    (query (:create-index 'test-idx :on 'test :using 'btree
    +        :fields (:->> 'data "field")
    +
    +(query (:create-index 'pointloc0 :on 'points :using 'gist
    +        :fields (:box 'location 'location)))
    +
    +(query (:create-index 'pointloc2 :on 'points :using 'gist
    +        :fields (:asc (:box 'location 'location)) (:nulls-last 'name)))
    +
    +
    +
    +
    +
    +
    +

    Indexes with storage parameters

    +
    +

    +To specify storage parameters (e.g. fillfactor=70, deduplicate_items=on, fastupdate = off or similar), use a :with keyword parameter and a form containing := operators, the storage parameter and the value. +

    +
    +
      (query (:create-index 'gin-idx :on 'documents-table :using gin
    +        :fields 'locations :with (:= 'fillfactor 70)))
    +
    +(query (:create-index 'title-index :on 'films :fields title
    +        :with (:= 'deduplicate-items 'off)))
    +
    +
    +

    +With multiple storage parameters: +

    +
    +
    (query (:create-index 'gin-idx :on 'documents-table :using gin
    +        :fields 'locations :with (:= 'deduplicate-items off) (:= 'fillfactor 70)))
    +
    +
    +
    +
    + +
    +

    Partial Indexes with where clauses

    +
    +

    +An example of a partial index: +

    +
    +
    (query (:create-index 'orders_unbilled_idx :on 'orders :fields 'order-nr
    +                 :where (:and (:is-not-true 'billed)
    +                              (:< 'order_nr 1000)))))
    +
    +
    +
    +
    +
    + +
    +

    Create-Table

    +
    +

    +Here we are talking about the S-SQL operator :create-table, not the create-table function name in Postmodern. First, starting at a minimum level, the :create-table and :create-extended-table operator calls are exactly the same. Let's walk through a simple example: +

    +
    +
    (query (:create-table 'films-at-eleven
    +    ((code :type (or (string 5) db-null) :constraint 'firstkey
    +           :primary-key t)
    +      (title :type (varchar 40))
    +      (did :type integer)
    +      (date-prod :type (or date db-null))
    +      (kind :type (or (varchar 10) db-null))
    +      (len :type (or interval db-null) :interval :hour-to-minute))))
    +
    +
    +
    + +

    +The parameter specification is :create-table (name (&rest columns) &rest options) +

    + +

    +The first parameter is the name of the new table. You could make the name a quoted string, e.g. "films-at-eleven", but postmodern will handle either a string or the unquoted parameter provided above. Postmodern will also automatically handle the conversion of the hyphens so beloved by common lisp programmers to the underscores demanded by the sql specification. +

    + +

    +The next form contains subforms for each column in the table. +

    + +

    +The first parameter being the name of the column. +

    + +

    +As you know, postgresql will enforce the data type for the column. So, the next keyword specifies that type to follow. You can see several different types specified in this table. Look at the type for 'code'. It specifies that the data will be either NULL or a string with a maximum length of 5 characters. +

    + +

    +Compare that against the type specifiers for title or did. In both of those cases, the column entry is not allowed to be NULL, it must have a value. In this example the title must be a string with a length no greater than 40 characters. (For most purposes, you can treat a string specification the same as a varchar specification. +

    + +

    +The did type specification mandates an integer - trying to put a float in that column will trigger a database type error. +

    + +

    +The date-prod column obviously has a date data type and the len column has a interval data type, intervals being a period of time rather than a specific time. +

    + +

    +The code column also has a constraint - It is the primary key for indexing the table and that contraint has a name - in this case 'firstkey. If you do not name the constraint, the system will name it for you. +

    + +

    +The len column also has additional information. It is an interval of time; That could encompass years as well as seconds. The specification given here, :hour-to-minute means that the database will only keep the hours to minutes part of the potential time interval. +

    +
    + +
    +

    Table Names Parameter

    +
    +

    +The following discussion on table names is the same for both :create-table or :create-extended table. +

    + +

    +Create-table works with either the simple name for the table parameter or the name can be wrapped in a form. There are a few acceptable ways to pass the table-name parameters. We recommend a single quote as in the first example below, but for backwards compatibility, you can also provide the table-name with no quotes at all. The last example below shows the table name preceded by the desired schema name. e.g. 'public.tablename1. +

    +
    +
    +(query (:create-table 'distributors-in-hell
    +                      ((did :type (or integer db-null)))))
    +
    +(query (:create-table (distributors-in-hell)
    +                      ((did :type (or integer db-null)))))
    +
    +(query (:create-table ("distributors-in-hell")
    +                      ((did :type (or integer db-null)))))
    +
    +(query (:create-table 'public.distributors-in-hell
    +                      ((did :type (or integer db-null)))))
    +
    +
    +
    +

    +Using the name wrapped in a form provides the opportunity to add additional qualifiers - if-not-exists, temp, and unlogged. +

    +
    +
    (query (:create-table (:if-not-exists 'distributors-in-hell)
    +
    +                      ((did :type (or integer db-null)))))
    +
    +
    +
    +
    + +
    +

    Temporary and Unlogged Tables

    +
    +

    +Temporary tables exists only for the duration of the session. To create them using s-sql in postmodern, the first parameter to :create-table should be a form where the first atom in the form is the keyword :temp. You can optionally use the :if-not-exists keyword, and then the name of the temporary table. E.g. +

    +
    +
    (query (:create-table (:temp 'distributors-in-hell)
    +                      ((did :type (or integer db-null)))))
    +
    +(query (:create-table (:temp :if-not-exists 'distributors-in-hell)
    +                     ((did :type (or integer db-null)))))
    +
    +
    +
    + +

    +Unlogged tables do not have their data written to the write-ahead log. As a result they are faster, but not crash safe. Any indexes created on an unlogged table are unlogged as well. The parameter signature is similar to a temporary table. E.g. +

    +
    +
    (query (:create-table (:unlogged 'distributors-in-hell)
    +                      ((did :type (or integer db-null)))))
    +
    +
    +
    +
    + +
    +

    Using Identity Columns

    +
    +

    +Postgresql version 10 added identity columns. These are auto-incrementing columns that use the standard SQL syntax instead of the serial and bigserial datatypes which are still available, but are not SQL standard syntax. The serial and bigserial datatypes also generate sequences that may have different usage permissions which can be problematic if you need to make changes to the sequence. +

    + +

    +There are two keyword alternatives that need to be considered: +

    + +
      +
    • :generated-as-identity-by-default (or more simply :identity-by-default)
    • +
    • :generated-as-identity-always (or more simply :identity-always)
    • +
    + +

    +The difference between the two alternatives is that if you try to insert or update a value in the column and the generated-always option is chosen, postgresql will raise an error. If you use the by-default option, postgresql will use your value rather than the automatically generated value. +

    + +

    +Note: The data type used for identity columns must be one of smallint, int, integer or bigint. +

    +
    +
    (query (:create-table 'color
    +                      ((color-id :type int :generated-as-identity-always t)
    +                       (color-name :type varchar))))
    +
    +(query (:create-table 'color
    +                      ((color-id :type int :generated-as-identity-by-default t)
    +                       (color-name :type varchar))))
    +
    +(query (:create-table 'color
    +                      ((color-id :type int :identity-always t)
    +                       (color-name :type varchar))))
    +
    +(query (:create-table 'color
    +                      ((color-id :type int :identity-by-default t)
    +                       (color-name :type varchar))))
    +
    +
    +
    +
    +
    + +
    +

    Array Columns

    +
    +

    +The following shows the creation of a table with a two dimensional array +

    +
    +
    (query (:create-table 'array-int
    +                      ((vector :type (or int[][] db-null)))))
    +
    +
    +
    +
    + +
    +

    Check Constraints

    +
    +

    +You can put a contraint on a table row that specifies values must meet certain requirements. In the following examples, the first puts a check constraint on a row, the second places at check constraint at the table level. +

    +
    +
    (query (:create-table 'distributors
    +                      ((did :type (or integer db-null) :check (:> 'did 100))
    +                       (name :type (or (varchar 40) db-null)))))
    +
    +(query (:create-table 'distributors
    +                      ((did :type (or integer db-null))
    +                       (name :type (or (varchar 40) db-null)))
    +                      (:constraint con1
    +                       :check (:and (:> 'did 100)
    +                                    (:<> 'name "")))))
    +
    +
    +
    +
    +
    + + +
    +

    Unique Constraints

    +
    +

    +You can ensure that a column or a combination of columns is unique without making that column or columns the primary key for the table. +

    + +

    +The first example sets a unique constraint at the column level of email, the second example sets a unique constraint at the table level. +

    + +

    +Please note the need to set :unique to t in the column constraint version. +

    +
    +
    (query (:create-table 'person
    +                      ((id :type serial :primary-key t)
    +                       (first-name :type (varchar 50))
    +                       (last-name :type (varchar 50))
    +                       (email :type (varchar 50) :unique t))))
    +
    +(query (:create-table 'films
    +                      ((code :type (or (string 5) db-null))
    +                       (title :type (or (varchar 40) db-null))
    +                       (did :type (or integer db-null))
    +                       (date-prod :type (or date db-null))
    +                       (kind :type (or (varchar 10) db-null))
    +                       (len :type (or interval db-null) :interval :hour-to-minute))
    +                      (:constraint production :unique 'date-prod)))
    +
    +
    +
    + +

    +This can get more complex if so desired. See the following example from the postgresql documentation, translated into s-sql. This level of complexity, however, requires the :create-extended-table method. +

    +
    +
    (query (:create-extended-table 'distributors
    +                               ((did :type (or integer db-null))
    +                                (name :type (or (varchar 40) db-null)))
    +                               ((:unique did :with (:= 'fillfactor 70)))))
    +
    +
    +
    + +

    +In case you are wondering, fillfactor is a storage parameter described in the postgresql documentation as: +

    + +

    +"The fillfactor for a table is a percentage between 10 and 100. 100 (complete packing) is the default. When a smaller fillfactor is specified, INSERT operations pack table pages only to the indicated percentage; the remaining space on each page is reserved for updating rows on that page. This gives UPDATE a chance to place the updated copy of a row on the same page as the original, which is more efficient than placing it on a different page. For a table whose entries are never updated, complete packing is the best choice, but in heavily updated tables smaller fillfactors are appropriate. This parameter cannot be set for TOAST tables." +

    +
    +
    + +
    +

    Timestamps with and without timezones

    +
    +

    +Ah, the bane of many programmers' existence - dates and times. At least the table creation is fairly straightforward. +

    + +

    +The following examples are fairly self explanatory. +

    +
    +
    (query (:create-table 'account-role
    +                      ((user-id :type integer)
    +                       (role-id :type integer)
    +                       (grant-date :type (or timestamp-without-time-zone db-null)))))
    +
    +(query (:create-table 'account-role
    +                      ((user-id :type integer)
    +                       (role-id :type integer)
    +                       (grant-date :type (or timestamp-with-time-zone db-null)))))
    +
    +(query (:create-table 'account-role
    +                      ((user-id :type integer)
    +                       (role-id :type integer)
    +                       (grant-date :type (or timestamptz db-null)))))
    +
    +(query (:create-table 'account-role
    +                      ((user-id :type integer)
    +                       (role-id :type integer)
    +                       (grant-date :type (or timestamp db-null)))))
    +
    +(query (:create-table 'account-role
    +                      ((user-id :type integer)
    +                       (role-id :type integer)
    +                       (grant-date :type (or time db-null)))))
    +
    +
    +
    +
    +
    + +
    +

    Adding Foreign Keys

    +
    +

    +There are a few different ways to add foreign keys in postgresql when defining a table. +

    +
    + +
    +

    Defining Foreign Keys at the Column Level

    +
    +

    +First with foreign key on the column. Use the keyword :references and specify the table name and the relevant column within the subform. You will see why the subform in a minute. +

    +
    +
    (query (:create-table 'so-items
    +                      ((item-id :type integer)
    +                       (so-id :type (or integer db-null)
    +                              :references ((so-headers id)))
    +                       (product-id :type (or integer db-null))
    +                       (qty :type (or integer db-null))
    +                       (net-price :type (or numeric db-null)))
    +                      (:primary-key item-id so-id)))
    +
    +
    +
    + +

    +If the foreign key references a group of columns in the foreign table, those fit into that same subform. +

    +
    +
    (query (:create-table 'so-items
    +                      ((item-id :type integer)
    +                       (so-id :type (or integer db-null)
    +                              :references ((so-headers id p1 p2)))
    +                       (product-id :type (or integer db-null))
    +                       (qty :type (or integer db-null))
    +                       (net-price :type (or numeric db-null)))
    +                      (:primary-key item-id so-id)))
    +
    +
    +
    + +

    +You can specify the actions to be taken if a row in the foreign table is deleted or updated. Per the postgresql documentation: +

    + +

    +"… when the data in the referenced columns is changed, certain actions are performed on the data in this table's columns. The ON DELETE clause specifies the action to perform when a referenced row in the referenced table is being deleted. Likewise, the ON UPDATE clause specifies the action to perform when a referenced column in the referenced table is being updated to a new value. If the row is updated, but the referenced column is not actually changed, no action is done. Referential actions other than the NO ACTION check cannot be deferred, even if the constraint is declared deferrable. There are the following possible actions for each clause: +

    + +

    +NO ACTION +

    + +

    +Produce an error indicating that the deletion or update would create a foreign key constraint violation. If the constraint is deferred, this error will be produced at constraint check time if there still exist any referencing rows. This is the default action in postgresql but the default in postmodern is restrict. +

    + +

    +RESTRICT +

    + +

    +Produce an error indicating that the deletion or update would create a foreign key constraint violation. This is the same as NO ACTION except that the check is not deferrable. +

    + +

    +CASCADE +

    + +

    +Delete any rows referencing the deleted row, or update the values of the referencing column(s) to the new values of the referenced columns, respectively. +

    + +

    +SET NULL +

    + +

    +Set the referencing column(s) to null. +

    + +

    +SET DEFAULT +

    + +

    +Set the referencing column(s) to their default values. (There must be a row in the referenced table matching the default values, if they are not null, or the operation will fail.) +

    + +

    +If the referenced column(s) are changed frequently, it might be wise to add an index to the referencing column(s) so that referential actions associated with the foreign key constraint can be performed more efficiently." +

    + +

    +So now examples with specifying the on-delete and on-update actions. +

    +
    +
    (query (:create-table 'so-items
    +                      ((item-id :type integer)
    +                       (so-id :type (or integer db-null)
    +                              :references ((so-headers id) :no-action :no-action))
    +                       (product-id :type (or integer db-null))
    +                       (qty :type (or integer db-null))
    +                       (net-price :type (or numeric db-null)))
    +                      (:primary-key item-id so-id)))
    +
    +
    +
    +
    +
    + +
    +

    Defining Foreign Keys at the Table Level

    +
    +

    +Instead of specifying the foreign keys at the column level, you can specify them at the table level, but of course that means you have to additionally specify which column in the current table is a foreign key. +

    + +

    +The following example creates a named constraint and a foreign key at column role-id with a single column in the foreign table. The first example uses the default actions for on-delete and on-default. The second example shows non-default actions specified. +

    +
    +
    (query (:create-table 'account-role
    +                      ((user-id :type integer)
    +                       (role-id :type integer)
    +                       (grant-date :type (or timestamp-without-time-zone db-null)))
    +                      (:primary-key user-id role-id)
    +                      (:constraint account-role-role-id-fkey :foreign-key (role-id) (role role-id))))
    +
    +(query (:create-table 'account-role
    +                      ((user-id :type integer)
    +                       (role-id :type integer)
    +                       (grant-date :type (or timestamp-without-time-zone db-null)))
    +                      (:primary-key user-id role-id)
    +                      (:constraint account-role-role-id-fkey :foreign-key (role-id) (role role-id) :no-action :no-action)))
    +
    +
    +

    +Additional foreign keys can easily be added: +

    +
    +
    (query (:create-table 'account-role
    +                      ((user-id :type integer)
    +                       (role-id :type integer)
    +                       (grant-date :type (or timestamp-without-time-zone db-null)))
    +                      (:primary-key user-id role-id)
    +                      (:constraint account-role-role-id-fkey :foreign-key (role-id) (role role-id))
    +                      (:constraint account-role-user-id-fkey :foreign-key (user-id) (users user-id))))
    +
    +
    +
    +
    +
    +
    +
    +

    Generated Columns

    +
    +

    +It is sometimes useful to have a generated column that is computed from something else. An example would be a tsvector type column which might be generated as in this example: +

    +
    +
    (query (:create-table 't10
    +                      ((title :type (or text db-null))
    +                       (body :type (or text db-null))
    +                       (tsv :type (or tsvector db-null)
    +                            :generated-always
    +                            (:to-tsvector "english" 'body)))))
    +
    +
    +

    +The following example uses a calculation from fields in the tuple: +

    +
    +
    (query (:create-table 't1
    +                      ((w :type (or real db-null))
    +                       (h :type (or real db-null))
    +                       (area :type (or real db-null)
    +                             :generated-always (:* 'w 'h)))))
    +
    +
    +

    +The final example uses a variable in the calculation of the generated column: +

    +
    +
    (let ((fx-rate 0.8))
    +       (query
    +        (:create-table 'cars
    +                       ((car-id :type (or int db-null))
    +                        (brand-name :type varchar)
    +                        (price-in-dollar :type (or numeric db-null)) (price-in-pound :type (or numeric db-null) :generated-always (:* 'price-in-dollar fx-rate))))))
    +
    +
    +
    +
    +
    +
    + + \ No newline at end of file diff --git a/doc/s-sql-c.org b/doc/s-sql-c.org new file mode 100644 index 0000000..b10b427 --- /dev/null +++ b/doc/s-sql-c.org @@ -0,0 +1,668 @@ +#+TITLE: S-SQL Examples C +#+OPTIONS: num:nil +#+HTML_HEAD: +#+HTML_HEAD: +#+OPTIONS: ^:nil + +* [[file:s-sql-examples.org][S-SQL Examples Home Page]] +| [[file:s-sql-a.org][A]]| [[file:s-sql-b.org][B]]| [[file:s-sql-c.org][C]]| [[file:s-sql-d.org][D]]| [[file:s-sql-e.org][E]]| [[file:s-sql-f.org][F]]| [[file:s-sql-g.org][G]]| [[file:s-sql-h.org][H]]| [[file:s-sql-i.org][I]]| [[file:s-sql-j.org][J]]| [[file:s-sql-k.org][K]]| [[file:s-sql-l.org][L]]| [[file:s-sql-m.org][M]]| [[file:s-sql-n.org][N]]| [[file:s-sql-o.org][O]]| [[file:s-sql-p.org][P]]| [[file:s-sql-r.org][R]]| [[file:s-sql-s.org][S]]| [[file:s-sql-t.org][T]]| [[file:s-sql-u.org][U]]| [[file:s-sql-v.org][V]]| [[file:s-sql-w.org][W]]| [[file:s-sql-special-characters.org][Special Characters]] | [[file:calling-postgresql-stored-functions.org][Calling Postgresql Stored Functions and Procedures]]| + +* Call + :PROPERTIES: + :CUSTOM_ID: call + :END: +Call is used to call a Postgresql Procedure. This cannot be used in a select clause. You can pass variables to the operator. +#+begin_src lisp + (query (:call 'set_x_procedure 1 13)) + + (let ((a 1) (b 2)) + (query (:call 'my-proc a b 3))) + + (let ((a 1) (b 2) (p 'my-proc)) + (query (:call p a b 3))) +#+end_src +* Case + :PROPERTIES: + :CUSTOM_ID: case + :END: +As you know, case is a conditional expression that you can use to either search for rows in a table when a condition is true or compare a table field to a statement in the case expression. So consider the following where you only look at the first 10 rows in the countries table. The Case expression indicates that if the id is less than five, return the word "Low" and if the id is greater than five, return the word "high". Notice what happens when Denmark, with an id of exactly five, gets returned. +#+begin_src lisp + (query (:select 'id 'name + (:case + ((:< 'id 5) "Low") + ((:> 'id 5) "High")) + :from 'countries + :where (:< 'id 10)))) + +((1 "Austria" "Low") (2 "Belgium" "Low") (4 "Canada" "Low") (5 "Denmark" :NULL) + (8 "France" "High") (9 "Germany" "High") (7 "Finland" "High")) + +#+end_src + +* Cast + :PROPERTIES: + :CUSTOM_ID: cast + :END: +There are two ways to cast in postmodern. First is the explicit use of cast as in: +#+begin_src lisp +(query (:select (:cast (:as "2018-04-19" 'date)) :from 'roadmap)) +#+end_src + +Then there is the use of the type operator which effectively translates into postgresql's :: casting shortcut. +#+begin_src lisp +(query (:select (:type "2018-04-19" date) :from 'roadmap)) +#+end_src + +Note that the targetted data type is quoted in the explicit use of cast and not quoted when using type. + +* Coalesce + :PROPERTIES: + :CUSTOM_ID: coalesce + :END: +The COALESCE function in SQL returns the first non-NULL expression among its arguments. +#+begin_src lisp + (query + (:order-by + (:select (:as 'countries.name 'country) + (:as (:coalesce 'countries.latitude 999) + 'latitude) + (:as (:coalesce 'countries.longitude 999) + 'longitude) + :from 'countries + :where (:and (:> 'countries.name '$1) + (:< 'countries.name '$2))) + 'country) + "D" "F") + + (("Denmark" 56 10) ("Dominican Republic" 19 -352/5) ("EU" 999 999) + ("East Timor" -17/2 2511/20) + ("Ecuador" -2 -773/10) ("Egypt" 27 30) ("El Salvador" 27/2 -1771/20) ("Estonia" 59 26) ("Ethiopia" 8 38)) +#+end_src + +* Constraints Examples + :PROPERTIES: + :CUSTOM_ID: constraints + :END: +Suppose you want to find the constraints on a particular table. You try something like this: +#+begin_src lisp + (query (:select '* + :from 'information-schema.table-constraints + :where (:= 'table-name "countries"))) + +(("mydatabase" "public" "countries_pkey" "mydatabase" "public" "countries" "PRIMARY KEY" "NO" "NO") + + ("mydatabase" "public" "country_name_uk" "mydatabase" "public" "countries" "UNIQUE" "NO" "NO") + + ("mydatabase" "public" "country_name_unique" "mydatabase" "public" "countries" "UNIQUE" "NO" "NO") + + ("mydatabase" "public" "2200_456618_1_not_null" "mydatabase" "public" "countries" "CHECK" "NO" "NO")) + +#+end_src + +Okay. That looks like it works. At a minimum, it is telling me that the countries table has a primary key named "countries_pkey". Also, for some strange reason, it has two unique constraints named "country_name_uk" and "country_name_unique". + +However consider table names with multiple words separated by underscores. If you are used to postmodern turning everything nicely into hyphens, you might try something like: +#+begin_src lisp + (query (:select '* :from 'information-schema.table-constraints + :where (:= 'table-name "countries-hyphenated-for-some-reason"))) + +#+end_src + +That will not work. Remember that you have to provide the actual string name of the table. Because sql does not like hyphens and demands underscores, the correct query in postmodern would look like this: +#+begin_src lisp + (query (:select '* :from 'information-schema.table-constraints + :where (:= 'table-name "countries_hyphenated_for_some_reason"))) + +#+end_src + +Or you could use s-sql:to-sql-name like this: +#+begin_src lisp + (query (:select '* + :from 'information-schema.table-constraints + :where (:= 'table-name '$1)) + (s-sql:to-sql-name 'tasks-lists)) + +#+end_src + +The query in this function generates information on the foreign key constraints in a database. Ignoring all the postgresql internal table names, while this looks complicated, the only additional items really here are :[] as the op for getting an array index, :generate-series, and :array-upper +#+begin_src lisp + (defun describe-foreign-key-constraints () + "Generates a list of lists of information on the foreign key constraints" + (query (:order-by (:select 'conname + (:as 'conrelid 'table) + (:as 'pgc.relname 'tabname) + (:as 'a.attname 'columns) + (:as 'confrelid 'foreign-table) + (:as 'pgf.relname 'ftabname) + (:as 'af.attname 'fcolumn) + :from + (:as 'pg_attribute 'af) + (:as 'pg_attribute 'a) + (:as 'pg_class 'pgc) + (:as 'pg_class 'pgf) + (:as + (:select 'conname 'conrelid 'confrelid + (:as (:[] 'conkey 'i) 'conkey) + (:as (:[] 'confkey 'i) 'confkey) + :from (:as (:select 'conname + 'conrelid 'confrelid + 'conkey 'confkey + (:as + (:generate-series '1 + :array-upper 'conkey 1)) + 'i) + :from 'pg_constraint + :where (:= 'contype "f" )) + 'ss)) + 'ss2) + :where (:and (:= 'af.attnum 'confkey) + (:= 'af.attrelid 'confrelid) + (:= 'a.attnum 'conkey) + (:= 'a.attrelid 'conrelid) + (:= 'pgf.relfilenode 'confrelid) + (:= 'pgc.relfilenode 'conrelid))) + 'ftabname 'fcolumn 'tabname 'columns)) + +#+end_src + +* Count + :PROPERTIES: + :CUSTOM_ID: count + :END: +The simplest use of count looks like this: +#+begin_src lisp + (query (:select (:count '*) :from 'countries) :single) + +202 +#+end_src + +* Create-Composite-Types + :PROPERTIES: + :CUSTOM_ID: create-composite-types + :END: +[[https://www.postgresql.org/docs/current/rowtypes.html][Composite types]] can be created with the :create-composite-type operator. For example: +#+begin_src lisp + (query (:create-composite-type 'inventory-item + (name string) + (df double-float) + (count bigint))) + + (query (:create-composite-type 'employee-type (name text) (salary numeric))) +#+end_src +Those types can then be used in :create-table queries. +#+begin_src lisp + (query (:create-table 'distributors + ((i :type inventory-item) + (e :type employee-type)))) +#+end_src + +* Create-Index + :PROPERTIES: + :CUSTOM_ID: create-index + :END: + ** Basic + :PROPERTIES: + :CUSTOM_ID: create-index-basic + :END: +To create a B-tree index on the column title in the table films. +#+begin_src lisp + (query (:create-index 'films_idx :on "films" :fields 'title)) +#+end_src +** Multiple Columns + :PROPERTIES: + :CUSTOM_ID: create-index-multiple-columns + :END: +Multiple-column indexes: +#+begin_src lisp + (query (:create-index 'films-idx :on "films" :fields 'title 'id)) +#+end_src +** Using Postgresql Expressions + :PROPERTIES: + :CUSTOM_ID: create-index-with-expression + :END: +To create an index on the postgresql expression lower so as to generate efficient case insensitive searches +#+begin_src lisp + (query (:create-index 'films_idx :on "films" :fields (:lower 'title))) +#+end_src +** GIN, GIST and other non-B-tree indexes + :PROPERTIES: + :CUSTOM_ID: create-index-other-methods + :END: +To create an index using e.g. GIN instead of a B-tree index, you need to provide a :using clause: +#+begin_src lisp + (query (:create-index 'films_idx :on "films" :using 'gin :fields 'title)) +#+end_src + +** Indexes with opclass parameters + :PROPERTIES: + :CUSTOM_ID: create-index-opclasses + :END: +The following basic opclass parameters are supported: +:asc, :desc, :nulls-first, :null-last, :nulls-distinct, :nulls-not-distinct, :array-ops, jsonb-ops, :jsonb-path-ops, :gin-trgm-ops, :tsvector-ops. + +To specify using an opclass parameter, you will need to enclose the specific field in its own form and use a keyword parameter. The second example shows a second field included in the index, but without an opclass parameter, so it does not need to be in its own form (although it can be): +#+begin_src lisp + (query (:create-index 'items-idx :on 'test-items :using 'gin + :fields (:jsonb-path-ops 'metadata))) + + (query (:create-index 'films-idx :on 'films :using 'gin + :fields (:nulls-first 'customer-id ) 'order-date)) + + (query (:create-index 'films-idx :on 'films :using 'gin + :fields (:nulls-first 'customer-id ) (:asc 'order-date))) +#+end_src +*** To-Tsvector + :PROPERTIES: + :CUSTOM_ID: create-index-to-tsvector + :END: + to-tsvector is a bit of a special case: + #+begin_src lisp + (query (:create-index 'pgweb-idx :on 'pgweb :using 'gin + :fields (:to-tsvector "english" 'body))) + #+end_src +*** 2+-ary Operators + :PROPERTIES: + :CUSTOM_ID: create-index-2-ary + :END: +These operators have two operands. They need to be in their own form: +#+begin_src lisp + (query (:create-index 'test-idx :on 'test :using 'btree + :fields (:->> 'data "field") + + (query (:create-index 'pointloc0 :on 'points :using 'gist + :fields (:box 'location 'location))) + + (query (:create-index 'pointloc2 :on 'points :using 'gist + :fields (:asc (:box 'location 'location)) (:nulls-last 'name))) +#+end_src +** Indexes with storage parameters + :PROPERTIES: + :CUSTOM_ID: create-index-storage-parameters + :END: +To specify storage parameters (e.g. fillfactor=70, deduplicate_items=on, fastupdate = off or similar), use a :with keyword parameter and a form containing := operators, the storage parameter and the value. +#+begin_src lisp + (query (:create-index 'gin-idx :on 'documents-table :using gin + :fields 'locations :with (:= 'fillfactor 70))) + + (query (:create-index 'title-index :on 'films :fields title + :with (:= 'deduplicate-items 'off))) +#+end_src +With multiple storage parameters: +#+begin_src lisp + (query (:create-index 'gin-idx :on 'documents-table :using gin + :fields 'locations :with (:= 'deduplicate-items off) (:= 'fillfactor 70))) +#+end_src + +** Partial Indexes with where clauses + :PROPERTIES: + :CUSTOM_ID: partial-indexes + :END: + An example of a partial index: +#+begin_src lisp + (query (:create-index 'orders_unbilled_idx :on 'orders :fields 'order-nr + :where (:and (:is-not-true 'billed) + (:< 'order_nr 1000))))) +#+end_src + +* Create-Table +:PROPERTIES: +:CUSTOM_ID: create-table +:END: +Here we are talking about the S-SQL operator :create-table, not the create-table function name in Postmodern. First, starting at a minimum level, the :create-table and :create-extended-table operator calls are exactly the same. Let's walk through a simple example: +#+begin_src lisp + (query (:create-table 'films-at-eleven + ((code :type (or (string 5) db-null) :constraint 'firstkey + :primary-key t) + (title :type (varchar 40)) + (did :type integer) + (date-prod :type (or date db-null)) + (kind :type (or (varchar 10) db-null)) + (len :type (or interval db-null) :interval :hour-to-minute)))) + +#+end_src + +The parameter specification is :create-table (name (&rest columns) &rest options) + +The first parameter is the name of the new table. You could make the name a quoted string, e.g. "films-at-eleven", but postmodern will handle either a string or the unquoted parameter provided above. Postmodern will also automatically handle the conversion of the hyphens so beloved by common lisp programmers to the underscores demanded by the sql specification. + +The next form contains subforms for each column in the table. + +The first parameter being the name of the column. + +As you know, postgresql will enforce the data type for the column. So, the next keyword specifies that type to follow. You can see several different types specified in this table. Look at the type for 'code'. It specifies that the data will be either NULL or a string with a maximum length of 5 characters. + +Compare that against the type specifiers for title or did. In both of those cases, the column entry is not allowed to be NULL, it must have a value. In this example the title must be a string with a length no greater than 40 characters. (For most purposes, you can treat a string specification the same as a varchar specification. + +The did type specification mandates an integer - trying to put a float in that column will trigger a database type error. + +The date-prod column obviously has a date data type and the len column has a interval data type, intervals being a period of time rather than a specific time. + +The code column also has a constraint - It is the primary key for indexing the table and that contraint has a name - in this case 'firstkey. If you do not name the constraint, the system will name it for you. + +The len column also has additional information. It is an interval of time; That could encompass years as well as seconds. The specification given here, :hour-to-minute means that the database will only keep the hours to minutes part of the potential time interval. + +** Table Names Parameter +:PROPERTIES: +:CUSTOM_ID: table-names-parameter +:END: +The following discussion on table names is the same for both :create-table or :create-extended table. + +Create-table works with either the simple name for the table parameter or the name can be wrapped in a form. There are a few acceptable ways to pass the table-name parameters. We recommend a single quote as in the first example below, but for backwards compatibility, you can also provide the table-name with no quotes at all. The last example below shows the table name preceded by the desired schema name. e.g. 'public.tablename1. +#+begin_src lisp + +(query (:create-table 'distributors-in-hell + ((did :type (or integer db-null))))) + +(query (:create-table (distributors-in-hell) + ((did :type (or integer db-null))))) + +(query (:create-table ("distributors-in-hell") + ((did :type (or integer db-null))))) + +(query (:create-table 'public.distributors-in-hell + ((did :type (or integer db-null))))) + +#+end_src +Using the name wrapped in a form provides the opportunity to add additional qualifiers - if-not-exists, temp, and unlogged. +#+begin_src lisp +(query (:create-table (:if-not-exists 'distributors-in-hell) + + ((did :type (or integer db-null))))) +#+end_src + +** Temporary and Unlogged Tables +:PROPERTIES: +:CUSTOM_ID: temp-tables +:END: +Temporary tables exists only for the duration of the session. To create them using s-sql in postmodern, the first parameter to :create-table should be a form where the first atom in the form is the keyword :temp. You can optionally use the :if-not-exists keyword, and then the name of the temporary table. E.g. +#+begin_src lisp +(query (:create-table (:temp 'distributors-in-hell) + ((did :type (or integer db-null))))) + +(query (:create-table (:temp :if-not-exists 'distributors-in-hell) + ((did :type (or integer db-null))))) + +#+end_src + +Unlogged tables do not have their data written to the write-ahead log. As a result they are faster, but not crash safe. Any indexes created on an unlogged table are unlogged as well. The parameter signature is similar to a temporary table. E.g. +#+begin_src lisp + (query (:create-table (:unlogged 'distributors-in-hell) + ((did :type (or integer db-null))))) +#+end_src + +** Using Identity Columns +:PROPERTIES: +:CUSTOM_ID: identity-columns +:END: +Postgresql version 10 added identity columns. These are auto-incrementing columns that use the standard SQL syntax instead of the serial and bigserial datatypes which are still available, but are not SQL standard syntax. The serial and bigserial datatypes also generate sequences that may have different usage permissions which can be problematic if you need to make changes to the sequence. + +There are two keyword alternatives that need to be considered: + +- :generated-as-identity-by-default (or more simply :identity-by-default) +- :generated-as-identity-always (or more simply :identity-always) + +The difference between the two alternatives is that if you try to insert or update a value in the column and the generated-always option is chosen, postgresql will raise an error. If you use the by-default option, postgresql will use your value rather than the automatically generated value. + +Note: The data type used for identity columns must be one of smallint, int, integer or bigint. +#+begin_src lisp +(query (:create-table 'color + ((color-id :type int :generated-as-identity-always t) + (color-name :type varchar)))) + +(query (:create-table 'color + ((color-id :type int :generated-as-identity-by-default t) + (color-name :type varchar)))) + +(query (:create-table 'color + ((color-id :type int :identity-always t) + (color-name :type varchar)))) + +(query (:create-table 'color + ((color-id :type int :identity-by-default t) + (color-name :type varchar)))) + +#+end_src + +** Array Columns +:PROPERTIES: +:CUSTOM_ID: arrayy-columns +:END: +The following shows the creation of a table with a two dimensional array +#+begin_src lisp + (query (:create-table 'array-int + ((vector :type (or int[][] db-null))))) +#+end_src + +** Check Constraints +:PROPERTIES: +:CUSTOM_ID: check-constraints +:END: +You can put a contraint on a table row that specifies values must meet certain requirements. In the following examples, the first puts a check constraint on a row, the second places at check constraint at the table level. +#+begin_src lisp + (query (:create-table 'distributors + ((did :type (or integer db-null) :check (:> 'did 100)) + (name :type (or (varchar 40) db-null))))) + + (query (:create-table 'distributors + ((did :type (or integer db-null)) + (name :type (or (varchar 40) db-null))) + (:constraint con1 + :check (:and (:> 'did 100) + (:<> 'name ""))))) + +#+end_src + + +** Unique Constraints +:PROPERTIES: +:CUSTOM_ID: unique-constraints +:END: +You can ensure that a column or a combination of columns is unique without making that column or columns the primary key for the table. + +The first example sets a unique constraint at the column level of email, the second example sets a unique constraint at the table level. + +Please note the need to set :unique to t in the column constraint version. +#+begin_src lisp +(query (:create-table 'person + ((id :type serial :primary-key t) + (first-name :type (varchar 50)) + (last-name :type (varchar 50)) + (email :type (varchar 50) :unique t)))) + +(query (:create-table 'films + ((code :type (or (string 5) db-null)) + (title :type (or (varchar 40) db-null)) + (did :type (or integer db-null)) + (date-prod :type (or date db-null)) + (kind :type (or (varchar 10) db-null)) + (len :type (or interval db-null) :interval :hour-to-minute)) + (:constraint production :unique 'date-prod))) + +#+end_src + +This can get more complex if so desired. See the following example from the postgresql documentation, translated into s-sql. This level of complexity, however, requires the :create-extended-table method. +#+begin_src lisp +(query (:create-extended-table 'distributors + ((did :type (or integer db-null)) + (name :type (or (varchar 40) db-null))) + ((:unique did :with (:= 'fillfactor 70))))) + +#+end_src + +In case you are wondering, fillfactor is a storage parameter described in the postgresql documentation as: + +"The fillfactor for a table is a percentage between 10 and 100. 100 (complete packing) is the default. When a smaller fillfactor is specified, INSERT operations pack table pages only to the indicated percentage; the remaining space on each page is reserved for updating rows on that page. This gives UPDATE a chance to place the updated copy of a row on the same page as the original, which is more efficient than placing it on a different page. For a table whose entries are never updated, complete packing is the best choice, but in heavily updated tables smaller fillfactors are appropriate. This parameter cannot be set for TOAST tables." + +** Timestamps with and without timezones +:PROPERTIES: +:CUSTOM_ID: timestamps +:END: +Ah, the bane of many programmers' existence - dates and times. At least the table creation is fairly straightforward. + +The following examples are fairly self explanatory. +#+begin_src lisp +(query (:create-table 'account-role + ((user-id :type integer) + (role-id :type integer) + (grant-date :type (or timestamp-without-time-zone db-null))))) + +(query (:create-table 'account-role + ((user-id :type integer) + (role-id :type integer) + (grant-date :type (or timestamp-with-time-zone db-null))))) + +(query (:create-table 'account-role + ((user-id :type integer) + (role-id :type integer) + (grant-date :type (or timestamptz db-null))))) + +(query (:create-table 'account-role + ((user-id :type integer) + (role-id :type integer) + (grant-date :type (or timestamp db-null))))) + +(query (:create-table 'account-role + ((user-id :type integer) + (role-id :type integer) + (grant-date :type (or time db-null))))) + +#+end_src + +** Adding Foreign Keys +:PROPERTIES: +:CUSTOM_ID: foreign-keys +:END: +There are a few different ways to add foreign keys in postgresql when defining a table. + +*** Defining Foreign Keys at the Column Level +:PROPERTIES: +:CUSTOM_ID: foreign-keys-at-column +:END: +First with foreign key on the column. Use the keyword :references and specify the table name and the relevant column within the subform. You will see why the subform in a minute. +#+begin_src lisp + (query (:create-table 'so-items + ((item-id :type integer) + (so-id :type (or integer db-null) + :references ((so-headers id))) + (product-id :type (or integer db-null)) + (qty :type (or integer db-null)) + (net-price :type (or numeric db-null))) + (:primary-key item-id so-id))) + +#+end_src + +If the foreign key references a group of columns in the foreign table, those fit into that same subform. +#+begin_src lisp + (query (:create-table 'so-items + ((item-id :type integer) + (so-id :type (or integer db-null) + :references ((so-headers id p1 p2))) + (product-id :type (or integer db-null)) + (qty :type (or integer db-null)) + (net-price :type (or numeric db-null))) + (:primary-key item-id so-id))) + +#+end_src + +You can specify the actions to be taken if a row in the foreign table is deleted or updated. Per the postgresql documentation: + +"… when the data in the referenced columns is changed, certain actions are performed on the data in this table's columns. The ON DELETE clause specifies the action to perform when a referenced row in the referenced table is being deleted. Likewise, the ON UPDATE clause specifies the action to perform when a referenced column in the referenced table is being updated to a new value. If the row is updated, but the referenced column is not actually changed, no action is done. Referential actions other than the NO ACTION check cannot be deferred, even if the constraint is declared deferrable. There are the following possible actions for each clause: + + NO ACTION + +Produce an error indicating that the deletion or update would create a foreign key constraint violation. If the constraint is deferred, this error will be produced at constraint check time if there still exist any referencing rows. This is the default action in postgresql but the default in postmodern is restrict. + + RESTRICT + +Produce an error indicating that the deletion or update would create a foreign key constraint violation. This is the same as NO ACTION except that the check is not deferrable. + + CASCADE + +Delete any rows referencing the deleted row, or update the values of the referencing column(s) to the new values of the referenced columns, respectively. + + SET NULL + +Set the referencing column(s) to null. + + SET DEFAULT + +Set the referencing column(s) to their default values. (There must be a row in the referenced table matching the default values, if they are not null, or the operation will fail.) + +If the referenced column(s) are changed frequently, it might be wise to add an index to the referencing column(s) so that referential actions associated with the foreign key constraint can be performed more efficiently." + +So now examples with specifying the on-delete and on-update actions. +#+begin_src lisp +(query (:create-table 'so-items + ((item-id :type integer) + (so-id :type (or integer db-null) + :references ((so-headers id) :no-action :no-action)) + (product-id :type (or integer db-null)) + (qty :type (or integer db-null)) + (net-price :type (or numeric db-null))) + (:primary-key item-id so-id))) + +#+end_src + +*** Defining Foreign Keys at the Table Level +:PROPERTIES: +:CUSTOM_ID: foreign-keys-at-table +:END: +Instead of specifying the foreign keys at the column level, you can specify them at the table level, but of course that means you have to additionally specify which column in the current table is a foreign key. + +The following example creates a named constraint and a foreign key at column role-id with a single column in the foreign table. The first example uses the default actions for on-delete and on-default. The second example shows non-default actions specified. +#+begin_src lisp +(query (:create-table 'account-role + ((user-id :type integer) + (role-id :type integer) + (grant-date :type (or timestamp-without-time-zone db-null))) + (:primary-key user-id role-id) + (:constraint account-role-role-id-fkey :foreign-key (role-id) (role role-id)))) + +(query (:create-table 'account-role + ((user-id :type integer) + (role-id :type integer) + (grant-date :type (or timestamp-without-time-zone db-null))) + (:primary-key user-id role-id) + (:constraint account-role-role-id-fkey :foreign-key (role-id) (role role-id) :no-action :no-action))) +#+end_src +Additional foreign keys can easily be added: +#+begin_src lisp +(query (:create-table 'account-role + ((user-id :type integer) + (role-id :type integer) + (grant-date :type (or timestamp-without-time-zone db-null))) + (:primary-key user-id role-id) + (:constraint account-role-role-id-fkey :foreign-key (role-id) (role role-id)) + (:constraint account-role-user-id-fkey :foreign-key (user-id) (users user-id)))) + +#+end_src +** Generated Columns +:PROPERTIES: +:CUSTOM_ID: generated-columns +:END: +It is sometimes useful to have a [[https://www.postgresql.org/docs/current/ddl-generated-columns.html][generated column]] that is computed from something else. An example would be a tsvector type column which might be generated as in this example: +#+begin_src lisp + (query (:create-table 't10 + ((title :type (or text db-null)) + (body :type (or text db-null)) + (tsv :type (or tsvector db-null) + :generated-always + (:to-tsvector "english" 'body))))) +#+end_src +The following example uses a calculation from fields in the tuple: +#+begin_src lisp + (query (:create-table 't1 + ((w :type (or real db-null)) + (h :type (or real db-null)) + (area :type (or real db-null) + :generated-always (:* 'w 'h))))) +#+end_src +The final example uses a variable in the calculation of the generated column: +#+begin_src lisp + (let ((fx-rate 0.8)) + (query + (:create-table 'cars + ((car-id :type (or int db-null)) + (brand-name :type varchar) + (price-in-dollar :type (or numeric db-null)) (price-in-pound :type (or numeric db-null) :generated-always (:* 'price-in-dollar fx-rate)))))) +#+end_src diff --git a/doc/s-sql-d.html b/doc/s-sql-d.html new file mode 100644 index 0000000..8182c06 --- /dev/null +++ b/doc/s-sql-d.html @@ -0,0 +1,591 @@ + + + + + + +S-SQL Examples D + + + + + + + +
    +
    +

    S-SQL Examples D

    +
    + +
    +

    S-SQL Examples Home Page

    +
    + + + +++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ + + + + + + + + + + + + + + + + + + + + + + + + + + + + +
    ABCDEFGHIJKLMNOPRSTUVWSpecial CharactersCalling Postgresql Stored Functions and Procedures
    +
    +
    + +
    +

    Data-types

    +
    +

    +I would note that if you are using insert-dao or update-dao, certain col-types will be enforced and throw errors. For example, smallint and boolean will throw errors if not provided the correct value types. Double-float will throw errors if provided a string. On the other hand, string will quite happily take an integer and and insert it into your database as a string. Providing a col-type of bpchar to some slot, even though postgresql will think that you want a single character, will not throw an error if you provide a string longer than a single character. +

    +
    + +
    +

    Numbers

    +
    +

    +Remember the test table from the introduction? It has a timestamp with timezone field called "date", a numeric field called "number-test" and a money field called "money". +

    + +

    +Lisp has a ratio datatype. In other words, instead of trying to come up with a floating point number for 1/3, common lisp simply views it as 1/3. But how does that translate into storage in postgresql? +

    +
    +
    (query (:insert-into 'test :set 'id 1 'number-test (/ 1 3) 'text "one third"))
    +
    +(query (:select 'number-test :from 'test :where (:= 'id 1)) :single)
    +
    +3333333333333333333333333333333333333/10000000000000000000000000000000000000
    +
    +
    +

    +We inserted a ratio 1/3 into the numeric field, then got something back that was not quite the same, but is decimal ratio truncated at 37 decimal points. +

    + +

    +Now insert that same ratio into the money field. +

    +
    +
    (query (:insert-into 'test :set 'id 1 'money (/ 1 3) 'text "one third money"))
    +
    +(query (:select 'money :from 'test :where (:= 'id 1)) :single)
    +
    +"$0.33"
    +
    +
    +

    +Here you notice that you got back a string that looks like a number truncated at two decimal points (the pennies). You would have to convert it to something else in order to perform any mathematical calculations. +

    + +

    +So, for example, you might reach for the wu-decimal package or the decimals package and call wu-decimal:parse-decimal or decimals:parse-decimal-number like so: +

    +
    +
    (wu-decimal:parse-decimal "$0.33" :start 1)
    +
    +33/100
    +
    +
    + +

    +Notice that we tried to start at 1 in order to get rid of the monetary indicator at the front. However, that doesn't work if the number was negative. Better is just removing the monetary indicator. +

    +
    +
    (wu-decimal:parse-decimal (remove #\$ "-$0.33"))
    +
    +-33/100
    +
    +
    + +

    +or, using the decimals package: +

    +
    +
    (decimals:parse-decimal-number (remove #\$ "-$0.33"))
    +
    +-33/100
    +
    +
    +
    +
    + + +
    +

    Timestamps with the local-time package

    +
    +

    +Postgresql keeps everything in a single timezone - UTC. Then everything else is set using the offset. See, e.g. http://www.postgresql.org/docs/current/datatype-datetime.html +

    + +

    +"For timestamp with time zone, the internally stored value is always in UTC (Universal Coordinated Time, traditionally known as Greenwich Mean Time, GMT). An input value that has an explicit time zone specified is converted to UTC using the appropriate offset for that time zone. If no time zone is stated in the input string, then it is assumed to be in the time zone indicated by the system's timezone parameter, and is converted to UTC using the offset for the timezone zone. +

    + +

    +When a timestamp with time zone value is output, it is always converted from UTC to the current timezone zone, and displayed as local time in that zone. To see the time in another time zone, either change timezone or use the AT TIME ZONE construct." +

    + +

    +So, looking at a server that is set for PDT, for table test with fields id, date, number_test, money and text +

    +
    +
    + +
    +

    Default with no timezone or offset:

    +
    +
    +
    (query (:insert-into 'test :set 'id 3 'text "insert here"
    +                     'date (local-time:encode-timestamp 0 0 0 12 01 01 2013)))
    +
    +2013-01-01 12:00:00-08
    +
    +
    +

    +(looking at the default timezone for the server, postgresql has set the timezone to UTC less 8 hours - UTC time would be 04:00:00) +

    + +

    +Using offset to explicitly offset 1 hour from UTC (e.g. Paris) +

    +
    +
    (query (:insert-into 'test :set 'id 4 'text "offset 1 hour"
    +                         'date (local-time:encode-timestamp 0 0 0 12 01 01 2013 :offset 3600)))
    +
    +2013-01-01 03:00:00-08
    +
    +
    + +

    +(looking at the default timezone for the server, postgresql has kept the timezone as PDT - UTC less 8 hours - but set the time as 03:00:00, which is 1 hour ahead of UTC) +

    + +

    +Using timezone to explicitly set it for UTC +

    +
    +
      (query (:insert-into 'test
    +                           :set 'id 5 'text "insert here using timezone utc"
    +                           'date (local-time:encode-timestamp 0 0 0 12 01 01 2013 :timezone local-time::+utc-zone+)))
    +
    +2013-01-01 04:00:00-08
    +
    +
    +

    +(looking at the default timezone for the server, postgresql has kept the timezone as PDT - UTC less 8 hours - but set the time as 04:00:00, which is the time in UTC relative to the PDT time at the server. +

    + +

    +See Time Functions for information on specific functions dealing with time. +

    +
    +
    + +
    +

    cl-postgres-datetime

    +
    +

    +Personally I like using cl-postgres-datetime. +Why? cl-postgres-datetime provides date/time integration for cl-postgres. It uses local-time for types that use time zones (i.e. timestamptz) and simple-date for types that don't (i.e. timestamp, date, time, interval). +

    +
    +
    +
    + +
    +

    Delete

    +
    +

    +A simple delete example using s-sql: +

    +
    +
    (query (:delete-from  'countries :where (:= 'id 284)))
    +
    +
    +

    +Slightly more complicated versions: +

    +
    +
    (query (:delete-from 'cd.members
    +        :where (:not (:in 'memid (:select 'memid :from 'cd.bookings)))))
    +
    +(query (:delete-from (:as 'cd.members 'mems)
    +        :where (:not (:exists (:select 1
    +                               :from 'cd.bookings
    +                               :where (:= 'memid 'mems.memid))))))
    +
    +
    +
    +
    + +
    +

    Desc

    +
    +

    +Normally, the use of :order-by would order the results in ascending order. You can apply :desc to a column and :asc to another column to re-arrange how the order-by rules will work. +

    +
    +
    (query (:order-by
    +        (:select 'id 'name :from 'regions)
    +        (:desc 'id)))
    +
    +((11 "Eastern Europe") (10 "Caribbean") (9 "Pacific") (8 "Central Asia")
    +                       (7 "South America") (6 "North America") (5 "Middle East")
    +                       (4 "Western Europe") (3 "Central America") (2 "Asia")
    +                       (1 "Africa"))
    +
    +
    +
    +
    + +
    +

    Distinct

    +
    +

    +The Distinct keyword is used to eliminate duplicative rows. In s-sql the keyword :distinct comes after the select arguments and prior to the keyword :from. +

    + +

    +The postmodern s-sql syntax would look like: +

    +
    +
      (query (:select 'regions.name :distinct
    +                :from 'countries 'regions
    +                :where (:and (:< 'latitude 0)
    +                             (:= 'regions.id 'region-id))))
    +
    +(("Pacific") ("Asia") ("Africa") ("South America"))
    +
    +
    +
    +
    + +
    +

    Distinct On

    +
    +

    +As indicated in the postgresql documentation, the DISTINCT ON clause is not part of the sql standard. A set of rows for which all the expressions are equal are considered duplicates and only the first row of the set is kept. This is a convenience but can have indeterminate results unless order by is used to ensure that the desired row appears first.. +

    + +

    +The postmodern s-sql syntax would look like: +

    +
    +
    (query (:select 'id 'name 'region-id :distinct-on 'region-id
    +        :from 'countries))
    +
    +((165 "Gabon" 1) (102 "Nepal" 2) (73 "Nicaragua" 3) (20 "UK" 4) (51 "Egypt" 5)
    +                 (166 "Greenland" 6) (75 "Honduras" 7) (184 "Turkmenistan" 8)(108 "Papua New Guinea" 9)
    +                 (121 "Antigua" 10) (67 "Belarus" 11))
    +
    +(query (:order-by
    +        (:select 'location 'time 'report
    +         :distinct-on 'location
    +         :from 'weather-reports)
    +        'location  (:desc 'time)))
    +
    +
    +
    +
    + +
    +

    Doquery

    +
    +

    +As stated in the postmodern documentation, doquery allows you to execute the given query (a string or a list starting with a keyword), iterating over the rows in the result. The body will be executed with the values in the row bound to the symbols given in names. To iterate over a parameterised query, one can specify a list whose car is the query, and whose cdr contains the arguments. +

    + +

    +The following is a toy function which illustrates the point. +

    +
    +
    (defun iterate-rows ()
    +  (let ((country-names ()))
    +    (doquery (:order-by (:select 'name
    +                         :from 'countries)
    +                        'name)
    +        (xname)
    +      (push xname country-names))
    +    country-names))
    +
    +
    +
    +
    +
    + + \ No newline at end of file diff --git a/doc/s-sql-d.org b/doc/s-sql-d.org new file mode 100644 index 0000000..9ab3d45 --- /dev/null +++ b/doc/s-sql-d.org @@ -0,0 +1,206 @@ +#+TITLE: S-SQL Examples D +#+OPTIONS: num:nil +#+HTML_HEAD: +#+HTML_HEAD: +#+OPTIONS: ^:nil + +* [[file:s-sql-examples.org][S-SQL Examples Home Page]] +| [[file:s-sql-a.org][A]]| [[file:s-sql-b.org][B]]| [[file:s-sql-c.org][C]]| [[file:s-sql-d.org][D]]| [[file:s-sql-e.org][E]]| [[file:s-sql-f.org][F]]| [[file:s-sql-g.org][G]]| [[file:s-sql-h.org][H]]| [[file:s-sql-i.org][I]]| [[file:s-sql-j.org][J]]| [[file:s-sql-k.org][K]]| [[file:s-sql-l.org][L]]| [[file:s-sql-m.org][M]]| [[file:s-sql-n.org][N]]| [[file:s-sql-o.org][O]]| [[file:s-sql-p.org][P]]| [[file:s-sql-r.org][R]]| [[file:s-sql-s.org][S]]| [[file:s-sql-t.org][T]]| [[file:s-sql-u.org][U]]| [[file:s-sql-v.org][V]]| [[file:s-sql-w.org][W]]| [[file:s-sql-special-characters.org][Special Characters]] | [[file:calling-postgresql-stored-functions.org][Calling Postgresql Stored Functions and Procedures]]| + +* Data-types + :PROPERTIES: + :CUSTOM_ID: data-types + :END: +I would note that if you are using insert-dao or update-dao, certain col-types will be enforced and throw errors. For example, smallint and boolean will throw errors if not provided the correct value types. Double-float will throw errors if provided a string. On the other hand, string will quite happily take an integer and and insert it into your database as a string. Providing a col-type of bpchar to some slot, even though postgresql will think that you want a single character, will not throw an error if you provide a string longer than a single character. + +** Numbers + :PROPERTIES: + :CUSTOM_ID: numbers + :END: +Remember the test table from the introduction? It has a timestamp with timezone field called "date", a numeric field called "number-test" and a money field called "money". + +Lisp has a ratio datatype. In other words, instead of trying to come up with a floating point number for 1/3, common lisp simply views it as 1/3. But how does that translate into storage in postgresql? +#+begin_src lisp + (query (:insert-into 'test :set 'id 1 'number-test (/ 1 3) 'text "one third")) + + (query (:select 'number-test :from 'test :where (:= 'id 1)) :single) + + 3333333333333333333333333333333333333/10000000000000000000000000000000000000 +#+end_src +We inserted a ratio 1/3 into the numeric field, then got something back that was not quite the same, but is decimal ratio truncated at 37 decimal points. + +Now insert that same ratio into the money field. +#+begin_src lisp + (query (:insert-into 'test :set 'id 1 'money (/ 1 3) 'text "one third money")) + + (query (:select 'money :from 'test :where (:= 'id 1)) :single) + + "$0.33" +#+end_src +Here you notice that you got back a string that looks like a number truncated at two decimal points (the pennies). You would have to convert it to something else in order to perform any mathematical calculations. + +So, for example, you might reach for the wu-decimal package or the decimals package and call wu-decimal:parse-decimal or decimals:parse-decimal-number like so: +#+begin_src lisp +(wu-decimal:parse-decimal "$0.33" :start 1) + +33/100 +#+end_src + +Notice that we tried to start at 1 in order to get rid of the monetary indicator at the front. However, that doesn't work if the number was negative. Better is just removing the monetary indicator. +#+begin_src lisp +(wu-decimal:parse-decimal (remove #\$ "-$0.33")) + +-33/100 +#+end_src + +or, using the decimals package: +#+begin_src lisp +(decimals:parse-decimal-number (remove #\$ "-$0.33")) + +-33/100 +#+end_src + + +** Timestamps with the local-time package + :PROPERTIES: + :CUSTOM_ID: local-time + :END: +Postgresql keeps everything in a single timezone - UTC. Then everything else is set using the offset. See, e.g. http://www.postgresql.org/docs/current/datatype-datetime.html + +"For timestamp with time zone, the internally stored value is always in UTC (Universal Coordinated Time, traditionally known as Greenwich Mean Time, GMT). An input value that has an explicit time zone specified is converted to UTC using the appropriate offset for that time zone. If no time zone is stated in the input string, then it is assumed to be in the time zone indicated by the system's timezone parameter, and is converted to UTC using the offset for the timezone zone. + +When a timestamp with time zone value is output, it is always converted from UTC to the current timezone zone, and displayed as local time in that zone. To see the time in another time zone, either change timezone or use the AT TIME ZONE construct." + +So, looking at a server that is set for PDT, for table test with fields id, date, number_test, money and text + +** Default with no timezone or offset: + :PROPERTIES: + :CUSTOM_ID: default-timestamps + :END: +#+begin_src lisp + (query (:insert-into 'test :set 'id 3 'text "insert here" + 'date (local-time:encode-timestamp 0 0 0 12 01 01 2013))) + + 2013-01-01 12:00:00-08 +#+end_src + (looking at the default timezone for the server, postgresql has set the timezone to UTC less 8 hours - UTC time would be 04:00:00) + +Using offset to explicitly offset 1 hour from UTC (e.g. Paris) +#+begin_src lisp + (query (:insert-into 'test :set 'id 4 'text "offset 1 hour" + 'date (local-time:encode-timestamp 0 0 0 12 01 01 2013 :offset 3600))) + + 2013-01-01 03:00:00-08 +#+end_src + + (looking at the default timezone for the server, postgresql has kept the timezone as PDT - UTC less 8 hours - but set the time as 03:00:00, which is 1 hour ahead of UTC) + +Using timezone to explicitly set it for UTC +#+begin_src lisp + (query (:insert-into 'test + :set 'id 5 'text "insert here using timezone utc" + 'date (local-time:encode-timestamp 0 0 0 12 01 01 2013 :timezone local-time::+utc-zone+))) + +2013-01-01 04:00:00-08 +#+end_src + (looking at the default timezone for the server, postgresql has kept the timezone as PDT - UTC less 8 hours - but set the time as 04:00:00, which is the time in UTC relative to the PDT time at the server. + +See Time Functions for information on specific functions dealing with time. + +** cl-postgres-datetime + :PROPERTIES: + :CUSTOM_ID: cl-postgres-datetime + :END: +Personally I like using [[https://github.com/chaitanyagupta/cl-postgres-datetime][cl-postgres-datetime]]. +Why? cl-postgres-datetime provides date/time integration for cl-postgres. It uses local-time for types that use time zones (i.e. timestamptz) and simple-date for types that don't (i.e. timestamp, date, time, interval). + +* Delete + :PROPERTIES: + :CUSTOM_ID: delete + :END: + A simple delete example using s-sql: +#+begin_src lisp + (query (:delete-from 'countries :where (:= 'id 284))) +#+end_src +Slightly more complicated versions: +#+begin_src lisp + (query (:delete-from 'cd.members + :where (:not (:in 'memid (:select 'memid :from 'cd.bookings))))) + + (query (:delete-from (:as 'cd.members 'mems) + :where (:not (:exists (:select 1 + :from 'cd.bookings + :where (:= 'memid 'mems.memid)))))) +#+end_src + +* Desc + :PROPERTIES: + :CUSTOM_ID: desc + :END: +Normally, the use of :order-by would order the results in ascending order. You can apply :desc to a column and :asc to another column to re-arrange how the order-by rules will work. +#+begin_src lisp + (query (:order-by + (:select 'id 'name :from 'regions) + (:desc 'id))) + + ((11 "Eastern Europe") (10 "Caribbean") (9 "Pacific") (8 "Central Asia") + (7 "South America") (6 "North America") (5 "Middle East") + (4 "Western Europe") (3 "Central America") (2 "Asia") + (1 "Africa")) +#+end_src + +* Distinct + :PROPERTIES: + :CUSTOM_ID: distinct + :END: +The Distinct keyword is used to eliminate duplicative rows. In s-sql the keyword :distinct comes after the select arguments and prior to the keyword :from. + +The postmodern s-sql syntax would look like: +#+begin_src lisp + (query (:select 'regions.name :distinct + :from 'countries 'regions + :where (:and (:< 'latitude 0) + (:= 'regions.id 'region-id)))) + +(("Pacific") ("Asia") ("Africa") ("South America")) +#+end_src + +* Distinct On + :PROPERTIES: + :CUSTOM_ID: distinct-on + :END: +As indicated in the [[https://www.postgresql.org/docs/current/sql-select.html][postgresql documentation]], the DISTINCT ON clause is not part of the sql standard. A set of rows for which all the expressions are equal are considered duplicates and only the first row of the set is kept. This is a convenience but can have indeterminate results unless order by is used to ensure that the desired row appears first.. + +The postmodern s-sql syntax would look like: +#+begin_src lisp + (query (:select 'id 'name 'region-id :distinct-on 'region-id + :from 'countries)) + + ((165 "Gabon" 1) (102 "Nepal" 2) (73 "Nicaragua" 3) (20 "UK" 4) (51 "Egypt" 5) + (166 "Greenland" 6) (75 "Honduras" 7) (184 "Turkmenistan" 8)(108 "Papua New Guinea" 9) + (121 "Antigua" 10) (67 "Belarus" 11)) + + (query (:order-by + (:select 'location 'time 'report + :distinct-on 'location + :from 'weather-reports) + 'location (:desc 'time))) +#+end_src + +* Doquery + :PROPERTIES: + :CUSTOM_ID: doquery + :END: +As stated in the [[file:postmodern.org][postmodern documentation]], doquery allows you to execute the given query (a string or a list starting with a keyword), iterating over the rows in the result. The body will be executed with the values in the row bound to the symbols given in names. To iterate over a parameterised query, one can specify a list whose car is the query, and whose cdr contains the arguments. + +The following is a toy function which illustrates the point. +#+begin_src lisp + (defun iterate-rows () + (let ((country-names ())) + (doquery (:order-by (:select 'name + :from 'countries) + 'name) + (xname) + (push xname country-names)) + country-names)) +#+end_src diff --git a/doc/s-sql-e.html b/doc/s-sql-e.html new file mode 100644 index 0000000..439a44f --- /dev/null +++ b/doc/s-sql-e.html @@ -0,0 +1,396 @@ + + + + + + +S-SQL Examples E + + + + + + + +
    +
    +

    S-SQL Examples E

    +
    + +
    +

    S-SQL Examples Home Page

    +
    + + + +++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ + + + + + + + + + + + + + + + + + + + + + + + + + + + + +
    ABCDEFGHIJKLMNOPRSTUVWSpecial CharactersCalling Postgresql Stored Functions and Procedures
    +
    +
    + + +
    +

    Enum

    +
    +

    +Per the postgresql documentation, Enumerated (enum) types are data types that comprise a static, ordered set of values. They are equivalent to the enum types supported in a number of programming languages. An example of an enum type might be the days of the week, or a set of status values for a piece of data. In this example, we are going to create an enumerated type "rainbow" with specific allowed colors. +

    +
    +
    (query (:create-enum 'rainbow
    +                     (list "red" "orange" "yellow" "green" "blue" "purple")))
    +
    +(query (:create-table test26
    +                      ((name :type text)
    +                       (color :type rainbow))))
    +
    +(query (:insert-into 'test26 :set 'name "Moe" 'current-color "yellow"))
    +
    +
    + +

    +Now if we try to insert an invalid type, we will trigger an error: +

    +
    +
    (query (:insert-into 'test26 :set 'name "Moe" 'current-color "chartreuse"))
    +
    +Database error 22P02: invalid input value for enum rainbow: "chartreuse" Query: insert into test26 values ('Moe', 'chartreuse')
    +
    +[Condition of type CL-POSTGRES-ERROR:DATA-EXCEPTION]
    +
    +
    +
    +
    + +
    +

    Except

    +
    +

    +The sql except operator returns rows that are in the first selection but not in the second selection. Following on with our like example, assume we want all countries with "New" in their name, but not countries with "Zealand" in their names. +

    +
    +
    (query (:except (:select 'id 'name
    +                         :from 'countries
    +                         :where (:like 'name "%New%"))
    +                (:select 'id 'name
    +                         :from 'countries
    +                         :where (:like 'name "%Zealand%"))))
    +
    +((108 "Papua New Guinea") (103 "New Caledonia"))
    +
    +
    +
    +
    +
    + +
    +

    Exists

    +
    +

    +Exists is used to run one subquery when a second subquery returns at least one row. For example: +

    +
    +
      (query (:select 'id 'name
    +                :from 'regions
    +                :where (:exists
    +                        (:select 'region-id
    +                                 :from 'countries
    +                                 :where (:and
    +                                         (:= 'countries.name "Costa Rica")
    +                                         (:= 'regions.id 'countries.region-id))))))
    +
    +((3 "Central America"))
    +
    +
    +
    +
    +
    + +
    +

    Extract

    +
    +
    +
    (query (:order-by (:select 'facid
    +                         (:as (:extract 'month 'starttime) 'month)
    +                         (:as (:sum 'slots) 'total-slots)
    +                         :from 'cd.bookings
    +                         :where (:and (:>= 'starttime "2012-01-01")
    +                                      (:< 'starttime "2013-01-01"))
    +                         :group-by 'facid 'month)
    +                'facid 'month))
    +
    +
    +
    +
    +
    + + \ No newline at end of file diff --git a/doc/s-sql-e.org b/doc/s-sql-e.org new file mode 100644 index 0000000..04360b4 --- /dev/null +++ b/doc/s-sql-e.org @@ -0,0 +1,85 @@ +#+TITLE: S-SQL Examples E +#+OPTIONS: num:nil +#+HTML_HEAD: +#+HTML_HEAD: +#+OPTIONS: ^:nil + +* [[file:s-sql-examples.org][S-SQL Examples Home Page]] +| [[file:s-sql-a.org][A]]| [[file:s-sql-b.org][B]]| [[file:s-sql-c.org][C]]| [[file:s-sql-d.org][D]]| [[file:s-sql-e.org][E]]| [[file:s-sql-f.org][F]]| [[file:s-sql-g.org][G]]| [[file:s-sql-h.org][H]]| [[file:s-sql-i.org][I]]| [[file:s-sql-j.org][J]]| [[file:s-sql-k.org][K]]| [[file:s-sql-l.org][L]]| [[file:s-sql-m.org][M]]| [[file:s-sql-n.org][N]]| [[file:s-sql-o.org][O]]| [[file:s-sql-p.org][P]]| [[file:s-sql-r.org][R]]| [[file:s-sql-s.org][S]]| [[file:s-sql-t.org][T]]| [[file:s-sql-u.org][U]]| [[file:s-sql-v.org][V]]| [[file:s-sql-w.org][W]]| [[file:s-sql-special-characters.org][Special Characters]] | [[file:calling-postgresql-stored-functions.org][Calling Postgresql Stored Functions and Procedures]]| + + +* Enum + :PROPERTIES: + :CUSTOM_ID: enum + :END: +Per the postgresql documentation, Enumerated (enum) types are data types that comprise a static, ordered set of values. They are equivalent to the enum types supported in a number of programming languages. An example of an enum type might be the days of the week, or a set of status values for a piece of data. In this example, we are going to create an enumerated type "rainbow" with specific allowed colors. +#+begin_src lisp + (query (:create-enum 'rainbow + (list "red" "orange" "yellow" "green" "blue" "purple"))) + + (query (:create-table test26 + ((name :type text) + (color :type rainbow)))) + + (query (:insert-into 'test26 :set 'name "Moe" 'current-color "yellow")) +#+end_src + +Now if we try to insert an invalid type, we will trigger an error: +#+begin_src lisp +(query (:insert-into 'test26 :set 'name "Moe" 'current-color "chartreuse")) + +Database error 22P02: invalid input value for enum rainbow: "chartreuse" Query: insert into test26 values ('Moe', 'chartreuse') + +[Condition of type CL-POSTGRES-ERROR:DATA-EXCEPTION] +#+end_src + +* Except + :PROPERTIES: + :CUSTOM_ID: except + :END: +The sql except operator returns rows that are in the first selection but not in the second selection. Following on with our like example, assume we want all countries with "New" in their name, but not countries with "Zealand" in their names. +#+begin_src lisp +(query (:except (:select 'id 'name + :from 'countries + :where (:like 'name "%New%")) + (:select 'id 'name + :from 'countries + :where (:like 'name "%Zealand%")))) + +((108 "Papua New Guinea") (103 "New Caledonia")) + +#+end_src + +* Exists + :PROPERTIES: + :CUSTOM_ID: exists + :END: +Exists is used to run one subquery when a second subquery returns at least one row. For example: +#+begin_src lisp + (query (:select 'id 'name + :from 'regions + :where (:exists + (:select 'region-id + :from 'countries + :where (:and + (:= 'countries.name "Costa Rica") + (:= 'regions.id 'countries.region-id)))))) + +((3 "Central America")) + +#+end_src + +* Extract + :PROPERTIES: + :CUSTOM_ID: extract + :END: +#+begin_src lisp + (query (:order-by (:select 'facid + (:as (:extract 'month 'starttime) 'month) + (:as (:sum 'slots) 'total-slots) + :from 'cd.bookings + :where (:and (:>= 'starttime "2012-01-01") + (:< 'starttime "2013-01-01")) + :group-by 'facid 'month) + 'facid 'month)) +#+end_src diff --git a/doc/s-sql-examples.html b/doc/s-sql-examples.html new file mode 100644 index 0000000..22c4930 --- /dev/null +++ b/doc/s-sql-examples.html @@ -0,0 +1,345 @@ + + + + + + +S-SQL Examples + + + + + + + +
    +
    +

    S-SQL Examples

    +
    + + + + +
    + + \ No newline at end of file diff --git a/doc/s-sql-examples.org b/doc/s-sql-examples.org new file mode 100644 index 0000000..4149c79 --- /dev/null +++ b/doc/s-sql-examples.org @@ -0,0 +1,52 @@ +#+TITLE: S-SQL Examples +#+OPTIONS: num:nil +#+HTML_HEAD: +#+HTML_HEAD: +#+OPTIONS: ^:nil + +* S-SQL examples + :PROPERTIES: + :CUSTOM_ID: s-sql-examples + :END: +| [[file:s-sql-a.org][A]]| [[file:s-sql-b.org][B]]| [[file:s-sql-c.org][C]]| [[file:s-sql-d.org][D]]| [[file:s-sql-e.org][E]]| [[file:s-sql-f.org][F]]| [[file:s-sql-g.org][G]]| [[file:s-sql-h.org][H]]| [[file:s-sql-i.org][I]]| [[file:s-sql-j.org][J]]| [[file:s-sql-k.org][K]]| [[file:s-sql-l.org][L]]| [[file:s-sql-m.org][M]]| [[file:s-sql-n.org][N]]| [[file:s-sql-o.org][O]]| [[file:s-sql-p.org][P]]| [[file:s-sql-r.org][R]]| [[file:s-sql-s.org][S]]| [[file:s-sql-t.org][T]]| [[file:s-sql-u.org][U]]| [[file:s-sql-v.org][V]]| [[file:s-sql-w.org][W]]| [[file:s-sql-special-characters.org][Special Characters]] | [[file:calling-postgresql-stored-functions.org][Calling Postgresql Stored Functions and Procedures]]| + +- [[file:intro-to-s-sql.org][Intro to S-SQL]] +- [[file:s-sql-a.org][a (and, alter-table, any and any*, as or alias, avg)]] +- [[file:s-sql-b.org][b (Between, Boolean Operators)]] +- [[file:s-sql-c.org][c (call, case, cast, coalesce, constraints, count, create-composite-types create-index, create-table)]] +- [[file:s-sql-d.org][d (data types (numbers and timestamps), delete, desc, distinct, distinct-on, doquery)]] +- [[file:s-sql-e.org][e (enum, except, exists, extract)]] +- [[file:s-sql-f.org][f (fetch, filter)]] +- [[file:s-sql-g.org][g (generate-series, group-by)]] +- [[file:s-sql-h.org][h (having)]] +- [[file:s-sql-i.org][i (insert, insert-into, intersect)]] +- [[file:s-sql-j.org][j (Joins)]] +- [[file:s-sql-l.org][l (lateral, like, ilike, limit)]] +- [[file:s-sql-m.org][m (many-to-many)]] +- [[file:s-sql-n.org][n (null, not-null, nullif)]] +- [[file:s-sql-o.org][o (on, on-conflict, or, order-by, order-by with limit and offset, over)]] +- [[file:s-sql-p.org][p (parameterized, partition-by)]] +- [[file:s-sql-r.org][r (random, raw, returning primary key, rollup)]] +- [[file:s-sql-s.org][s (Set, sql-type-name, string_agg, sum)]] +- [[file:s-sql-t.org][t (threads, time functions, to-tsquery, to-tsvector, truncate)]] +- [[file:s-sql-u.org][u (union, union-all, unique, update, upsert, using)]] +- [[file:s-sql-v.org][v (create-view, variable parameters)]] +- [[file:s-sql-w.org][w (when, window, with, with-recursive)]] + +- [[file:array-notes.html][Array-Notes]] +- [[file:calling-postgresql-stored-functions.org][Calling Postgresql Stored Functions and Procedures]] +- [[file:dao-classes.html][Database Access Object (Dao) Classes]] +- [[file:interval-notes.html][Interval Notes]] +- [[file:isolation-notes.html][Isolation Notes]] +- [[file:s-sql-postgresql-functions.org][S-SQL and Postgresql Functions]] +- [[file:s-sql-prepared-statements.org][S-SQL and Prepared Statements]] +- [[file:s-sql-special-characters.org][Special Characters]] + +* References + :PROPERTIES: + :CUSTOM_ID: references + :END: +- [[file:index.org][Documentation Index]] +- [[file:s-sql.org][S-SQL Reference]] +- [[file:postmodern.org][Postmodern Reference]] +- [[file:cl-postgres.org][Cl-Postgres Reference]] diff --git a/doc/s-sql-f.html b/doc/s-sql-f.html new file mode 100644 index 0000000..96d5de5 --- /dev/null +++ b/doc/s-sql-f.html @@ -0,0 +1,353 @@ + + + + + + +S-SQL Examples F + + + + + + + +
    +
    +

    S-SQL Examples F

    +
    + +
    +

    S-SQL Examples Home Page

    +
    + + + +++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ + + + + + + + + + + + + + + + + + + + + + + + + + + + + +
    ABCDEFGHIJKLMNOPRSTUVWSpecial CharactersCalling Postgresql Stored Functions and Procedures
    +
    +
    + +
    +

    Fetch

    +
    +

    +Fetch is a more efficient way to do pagination instead of using limit and +offset. Fetch allows you to retrieve a limited set of rows, optionally offset +by a specified number of rows. In order to ensure this works correctly, you +should use the order-by clause. If the amount is not provided, it assumes +you only want to return 1 row. +https://www.postgresql.org/docs/current/sql-select.html +

    + +

    +Examples: +

    +
    +
    (query (:fetch (:order-by (:select 'id :from 'historical-events) 'id) 5))
    +
    +((1) (2) (3) (4) (5))
    +
    +(query (:fetch (:order-by (:select 'id :from 'historical-events) 'id) 5 10))
    +
    +((11) (12) (13) (14) (15))
    +
    +
    +
    +
    + +
    +

    Filter

    +
    +
    +
    (query (:select (:as (:count '* :distinct) 'unfiltered)
    +                (:as (:count '* :filter (:= 1 'bid))
    +                     'filtered)
    +                :from 'testtable))
    +
    +
    +

    +Note that, if used, the filter must be last in the count args. If distinct +is used, it must come before filter. Unlike standard sql, the word 'where' +is not used inside the filter clause. E.g. +

    +
    +
    (query (:select (:count '*)
    +                (:count '* :filter (:= 1 'bid))
    +                'id
    +                :from 'pbbench-history))
    +
    +
    +
    +
    +
    + + \ No newline at end of file diff --git a/doc/s-sql-f.org b/doc/s-sql-f.org new file mode 100644 index 0000000..fded58f --- /dev/null +++ b/doc/s-sql-f.org @@ -0,0 +1,50 @@ +#+TITLE: S-SQL Examples F +#+OPTIONS: num:nil +#+HTML_HEAD: +#+HTML_HEAD: +#+OPTIONS: ^:nil + +* [[file:s-sql-examples.org][S-SQL Examples Home Page]] +| [[file:s-sql-a.org][A]]| [[file:s-sql-b.org][B]]| [[file:s-sql-c.org][C]]| [[file:s-sql-d.org][D]]| [[file:s-sql-e.org][E]]| [[file:s-sql-f.org][F]]| [[file:s-sql-g.org][G]]| [[file:s-sql-h.org][H]]| [[file:s-sql-i.org][I]]| [[file:s-sql-j.org][J]]| [[file:s-sql-k.org][K]]| [[file:s-sql-l.org][L]]| [[file:s-sql-m.org][M]]| [[file:s-sql-n.org][N]]| [[file:s-sql-o.org][O]]| [[file:s-sql-p.org][P]]| [[file:s-sql-r.org][R]]| [[file:s-sql-s.org][S]]| [[file:s-sql-t.org][T]]| [[file:s-sql-u.org][U]]| [[file:s-sql-v.org][V]]| [[file:s-sql-w.org][W]]| [[file:s-sql-special-characters.org][Special Characters]] | [[file:calling-postgresql-stored-functions.org][Calling Postgresql Stored Functions and Procedures]]| + +* Fetch + :PROPERTIES: + :CUSTOM_ID: fetch + :END: +Fetch is a more efficient way to do pagination instead of using limit and +offset. Fetch allows you to retrieve a limited set of rows, optionally offset +by a specified number of rows. In order to ensure this works correctly, you +should use the order-by clause. If the amount is not provided, it assumes +you only want to return 1 row. +https://www.postgresql.org/docs/current/sql-select.html + +Examples: +#+BEGIN_SRC lisp +(query (:fetch (:order-by (:select 'id :from 'historical-events) 'id) 5)) + +((1) (2) (3) (4) (5)) + +(query (:fetch (:order-by (:select 'id :from 'historical-events) 'id) 5 10)) + +((11) (12) (13) (14) (15)) +#+END_SRC + +* Filter + :PROPERTIES: + :CUSTOM_ID: filter + :END: +#+BEGIN_SRC lisp +(query (:select (:as (:count '* :distinct) 'unfiltered) + (:as (:count '* :filter (:= 1 'bid)) + 'filtered) + :from 'testtable)) +#+END_SRC +Note that, if used, the filter must be last in the count args. If distinct +is used, it must come before filter. Unlike standard sql, the word 'where' +is not used inside the filter clause. E.g. +#+BEGIN_SRC lisp +(query (:select (:count '*) + (:count '* :filter (:= 1 'bid)) + 'id + :from 'pbbench-history)) +#+END_SRC diff --git a/doc/s-sql-g.html b/doc/s-sql-g.html new file mode 100644 index 0000000..4a60082 --- /dev/null +++ b/doc/s-sql-g.html @@ -0,0 +1,345 @@ + + + + + + +S-SQL Examples G + + + + + + + +
    +
    +

    S-SQL Examples G

    +
    + +
    +

    S-SQL Examples Home Page

    +
    + + + +++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ + + + + + + + + + + + + + + + + + + + + + + + + + + + + +
    ABCDEFGHIJKLMNOPRSTUVWSpecial CharactersCalling Postgresql Stored Functions and Procedures
    +
    +
    + +
    +

    Generate-Series

    +
    +
    +
    (query (:select 'x (:generate-series 0 'x)
    +                           :from (:as (:values (:set 0) (:set 1) (:set 2))
    +                                      (:t 'x))))
    +
    +'((0 0) (1 0) (1 1) (2 0) (2 1) (2 2))
    +
    +
    +
    +
    +
    +

    Group-By

    +
    +

    +The following two examples use group-by. The first determines the number of countries in my table in each region and returns the list in region name order. The second determines the country with the maximum latitude for each region. +

    + +
    +
    (query (:order-by
    +        (:select 'regions.name
    +                 (:count 'regions.name)
    +                 :from 'countries 'regions
    +         :where (:= 'regions.id 'countries.region-id)
    +         :group-by 'regions.name)
    +        'regions.name))
    +
    +(("Africa" 38) ("Asia" 27) ("Caribbean" 15) ("Central America" 6)("Central Asia" 5) ("Eastern Europe" 11)
    +               ("Middle East" 13) ("North America" 5)("Pacific" 24) ("South America" 14)
    +               ("Western Europe" 39))
    +
    +(query (:select 'regions.name (:max 'latitude)
    +                :from 'countries 'regions
    +        :where (:= 'regions.id 'region-id)
    +        :group-by 'regions.name))
    +
    +(("Pacific" 378/25) ("Western Europe" 65) ("Asia" 46) ("Central Asia" 48)("Caribbean" 483/20) ("Eastern Europe" 60)
    +                    ("North America" 72) ("Middle East" 39)("Central America" 343/20) ("Africa" 34) ("South America" 15))
    +
    +
    +
    +
    +
    + + \ No newline at end of file diff --git a/doc/s-sql-g.org b/doc/s-sql-g.org new file mode 100644 index 0000000..99ed66e --- /dev/null +++ b/doc/s-sql-g.org @@ -0,0 +1,47 @@ +#+TITLE: S-SQL Examples G +#+OPTIONS: num:nil +#+HTML_HEAD: +#+HTML_HEAD: +#+OPTIONS: ^:nil + +* [[file:s-sql-examples.org][S-SQL Examples Home Page]] +| [[file:s-sql-a.org][A]]| [[file:s-sql-b.org][B]]| [[file:s-sql-c.org][C]]| [[file:s-sql-d.org][D]]| [[file:s-sql-e.org][E]]| [[file:s-sql-f.org][F]]| [[file:s-sql-g.org][G]]| [[file:s-sql-h.org][H]]| [[file:s-sql-i.org][I]]| [[file:s-sql-j.org][J]]| [[file:s-sql-k.org][K]]| [[file:s-sql-l.org][L]]| [[file:s-sql-m.org][M]]| [[file:s-sql-n.org][N]]| [[file:s-sql-o.org][O]]| [[file:s-sql-p.org][P]]| [[file:s-sql-r.org][R]]| [[file:s-sql-s.org][S]]| [[file:s-sql-t.org][T]]| [[file:s-sql-u.org][U]]| [[file:s-sql-v.org][V]]| [[file:s-sql-w.org][W]]| [[file:s-sql-special-characters.org][Special Characters]] | [[file:calling-postgresql-stored-functions.org][Calling Postgresql Stored Functions and Procedures]]| + +* Generate-Series + :PROPERTIES: + :CUSTOM_ID: generate-series + :END: +#+begin_src lisp + (query (:select 'x (:generate-series 0 'x) + :from (:as (:values (:set 0) (:set 1) (:set 2)) + (:t 'x)))) + + '((0 0) (1 0) (1 1) (2 0) (2 1) (2 2)) +#+end_src +* Group-By + :PROPERTIES: + :CUSTOM_ID: group-by + :END: +The following two examples use group-by. The first determines the number of countries in my table in each region and returns the list in region name order. The second determines the country with the maximum latitude for each region. + +#+begin_src lisp + (query (:order-by + (:select 'regions.name + (:count 'regions.name) + :from 'countries 'regions + :where (:= 'regions.id 'countries.region-id) + :group-by 'regions.name) + 'regions.name)) + + (("Africa" 38) ("Asia" 27) ("Caribbean" 15) ("Central America" 6)("Central Asia" 5) ("Eastern Europe" 11) + ("Middle East" 13) ("North America" 5)("Pacific" 24) ("South America" 14) + ("Western Europe" 39)) + + (query (:select 'regions.name (:max 'latitude) + :from 'countries 'regions + :where (:= 'regions.id 'region-id) + :group-by 'regions.name)) + + (("Pacific" 378/25) ("Western Europe" 65) ("Asia" 46) ("Central Asia" 48)("Caribbean" 483/20) ("Eastern Europe" 60) + ("North America" 72) ("Middle East" 39)("Central America" 343/20) ("Africa" 34) ("South America" 15)) +#+end_src diff --git a/doc/s-sql-h.html b/doc/s-sql-h.html new file mode 100644 index 0000000..10f2ef9 --- /dev/null +++ b/doc/s-sql-h.html @@ -0,0 +1,319 @@ + + + + + + +S-SQL Examples H + + + + + + + +
    +
    +

    S-SQL Examples H

    +
    + +
    +

    S-SQL Examples Home Page

    +
    + + + +++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ + + + + + + + + + + + + + + + + + + + + + + + + + + + + +
    ABCDEFGHIJKLMNOPRSTUVWSpecial CharactersCalling Postgresql Stored Functions and Procedures
    +
    +
    + +
    +

    Having

    +
    +

    +Postgresql documentation here +

    +
    +
      (query (:select (:count 'c.id) 'r.name
    +                :from (:as 'countries 'c)
    +                :inner-join (:as 'regions 'r)
    +                :on (:= 'c.region-id 'r.id)
    +                :group-by 'r.name
    +                :having (:< (:count 'c.id) 10)))
    +
    +((5 "Central Asia") (5 "North America") (6 "Central America"))
    +
    +
    +
    +
    +
    + + \ No newline at end of file diff --git a/doc/s-sql-h.org b/doc/s-sql-h.org new file mode 100644 index 0000000..d69cf93 --- /dev/null +++ b/doc/s-sql-h.org @@ -0,0 +1,24 @@ +#+TITLE: S-SQL Examples H +#+OPTIONS: num:nil +#+HTML_HEAD: +#+HTML_HEAD: +#+OPTIONS: ^:nil + +* [[file:s-sql-examples.org][S-SQL Examples Home Page]] +| [[file:s-sql-a.org][A]]| [[file:s-sql-b.org][B]]| [[file:s-sql-c.org][C]]| [[file:s-sql-d.org][D]]| [[file:s-sql-e.org][E]]| [[file:s-sql-f.org][F]]| [[file:s-sql-g.org][G]]| [[file:s-sql-h.org][H]]| [[file:s-sql-i.org][I]]| [[file:s-sql-j.org][J]]| [[file:s-sql-k.org][K]]| [[file:s-sql-l.org][L]]| [[file:s-sql-m.org][M]]| [[file:s-sql-n.org][N]]| [[file:s-sql-o.org][O]]| [[file:s-sql-p.org][P]]| [[file:s-sql-r.org][R]]| [[file:s-sql-s.org][S]]| [[file:s-sql-t.org][T]]| [[file:s-sql-u.org][U]]| [[file:s-sql-v.org][V]]| [[file:s-sql-w.org][W]]| [[file:s-sql-special-characters.org][Special Characters]] | [[file:calling-postgresql-stored-functions.org][Calling Postgresql Stored Functions and Procedures]]| + +* Having + :PROPERTIES: + :CUSTOM_ID: having + :END: + Postgresql documentation [[https://www.postgresql.org/docs/current/queries-table-expressions.html#QUERIES-GROUP][here]] +#+begin_src lisp + (query (:select (:count 'c.id) 'r.name + :from (:as 'countries 'c) + :inner-join (:as 'regions 'r) + :on (:= 'c.region-id 'r.id) + :group-by 'r.name + :having (:< (:count 'c.id) 10))) + +((5 "Central Asia") (5 "North America") (6 "Central America")) +#+end_src diff --git a/doc/s-sql-i.html b/doc/s-sql-i.html new file mode 100644 index 0000000..e35bb44 --- /dev/null +++ b/doc/s-sql-i.html @@ -0,0 +1,784 @@ + + + + + + +S-SQL Examples I + + + + + + + +
    +
    +

    S-SQL Examples I

    +
    + +
    +

    S-SQL Examples Home Page

    +
    + + + +++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ + + + + + + + + + + + + + + + + + + + + + + + + + + + + +
    ABCDEFGHIJKLMNOPRSTUVWSpecial CharactersCalling Postgresql Stored Functions and Procedures
    +
    +
    + +
    +

    ilike

    + +
    + +
    +

    In

    +
    +
    +
    (query (:select 'name
    +              :from 'countries
    +              :where (:in 'id
    +                          (:set 20 21 23))))
    +
    +
    +
    +
    + +
    +

    Insert, Insert-into

    +
    +
    +
    +

    First, without s-sql

    +
    +
    +
    (query "insert into 'countries values (920, 'Oz', 'Oz Dollars')")
    +
    +
    +
    +
    + +
    +

    With s-sql

    +
    +

    +There are two ways to use s-sql with basic single row inserts. First, directly setting the columns, using the :set keyword and alternating column names and values. This means that the :insert-into clause expects the arguments to :set to be in multiples of two. Odd arguments will trigger an error. +

    +
    +
    (query (:insert-into 'countries :set 'id 920 'name "Oz"
    +                                   'currency "Oz Dollars"))
    +
    +
    +

    +Notice that a list with two items is a single item, not a multiple of two. You can use sql-compile to deal with this. See this example from the mailing list. +

    +
    +
    (sql-compile `(:insert-into 'kupci :set ,@(when t (list 'ime "a"))))
    +
    +
    +

    +The second method, without the :set keyword, uses :select, followed by values. +

    +
    +
    (query (:insert-into 'countries (:select "Oz" "Oz Dollars")))
    +
    +(query (:insert-into 'test2 (:select '* :from 'test1)))
    +
    +
    +
    +
    + +
    +

    Returning the Primary Key

    +
    +

    +Suppose your table has a serial key of id and you want the insert function to return the newly generated id for that new record. +

    +
    +
    (query (:insert-into 'categories :set 'name "test-cat3" :returning 'id)
    +     :single)
    +
    +
    +

    +The next example shows the same example using parameterized variables. +

    +
    +
    (let ((name "test-cat4"))
    +  (query (:insert-into 'categories :set 'name '$1 :returning 'id)
    +         name :single))
    +
    +
    +

    +Note: This is a postgresql extension to the standard From the Documentation: +

    + +

    +INSERT conforms to the SQL standard, except that the RETURNING clause is a PostgreSQL extension, as is the ability to use WITH with INSERT, and the ability to specify an alternative action with ON CONFLICT. Also, the case in which a column name list is omitted, but not all the columns are filled from the VALUES clause or query, is disallowed by the standard. +

    + +

    +The SQL standard specifies that OVERRIDING SYSTEM VALUE can only be specified if an identity column that is generated always exists. PostgreSQL allows the clause in any case and ignores it if it is not applicable. +With DAOs +

    +
    +
    +
    +

    Insert-DAO

    +
    +

    +Postmodern has an update-dao and an insert-dao function. You could check and see if the dao that you are currently dealing with has its primary key set (in which case you are editing an existing object and need to use update-dao. If not, then you dealing with a brand new object and will need to set the primary key and use the insert-dao method, using something like this: +

    +
    +
    (if (id item) (postmodern:update-dao item)
    +    (progn (setf (id item) (get-next-id class-name))
    +       (postmodern:insert-dao item)))
    +
    +
    +

    +However, you could also just use upsert. +

    +
    +
    (postmodern:upsert-dao item)
    +
    +
    +
    +
    + +
    +

    Multiple Row Inserts

    +
    +

    +You can use s-sql to generate INSERT INTO clauses with multiple rows, e.g. "INSERT INTO \"table\" (a, b) VALUES (10, 20), (30, 40)". (This ability does not yet exist with respect to inserting multiple daos. +

    + +

    +First, without specifying columns: +

    +
    +
    (query (:insert-rows-into 'my-table :values '((42 "foobar") (23 "foobaz"))))
    +
    +
    +

    +Now with specifying columns: +

    +
    +
    (query (:insert-rows-into 'table
    +                 :columns 'a 'b
    +                 :values '((10 20) (30 40))))
    +
    +(query (:insert-rows-into 'cd.facilities
    +                 :columns 'facid 'name 'membercost 'guestcost 'initialoutlay 'monthlymaintenance
    +                 :values '((9 "Spa" 20 30 100000 800)
    +                           (10 "Squash Court 2" 3.5 17.5 5000 80))))
    +
    +
    +

    +Using a select statement: +

    +
    +
    (query (:insert-rows-into 'cd.facilities
    +                 :columns 'facid 'name 'membercost 'guestcost 'initialoutlay 'monthlymaintenance
    +                 :values '(((:select (:+ (:select (:max 'facid)
    +                                          :from 'cd.facilities)
    +                                      1))
    +                            "Spa" 20 30 100000 800))))
    +
    +
    +

    +Overriding System Values: +

    +
    +
    (query (:insert-rows-into 'table1
    +        :columns 'c1 'c2
    +        :overriding-system-value
    +        :values '((1 "a") (2 "b"))))
    +
    +
    +
    +
    +
    +

    Insert-Rows-On-Conflict-Do-Nothing

    +
    +

    +Inserting rows with on conflict do nothing +

    +
    +
    (query (:insert-rows-into 'distributors
    +                 :columns 'did 'dname
    +                 :values '((7 "Readline GmbH"))
    +                 :on-conflict-do-nothing))
    +
    +
    +

    +:on-conflict with separate :do-nothing keyword +

    +
    +
    (query (:insert-rows-into 'test :columns 'some-key 'some-val
    +                                   :values '(("a" 5) ("b" 6) ("c" 7))
    +                                   :on-conflict 'some-key
    +                                   :do-nothing))
    +
    +
    +

    +With where condition +

    +
    +
    (query (:insert-rows-into 'distributors
    +                 :columns 'did 'dname
    +                 :values '((10 "Conrad International"))
    +                 :on-conflict 'did
    +                 :do-nothing
    +                 :where 'is-active))
    +
    +
    +

    +With returning +

    +
    +
    (query (:insert-rows-into 'distributors
    +        :columns 'did 'dname
    +                          :values '((8 "Readline GmbH"))
    +                          :on-conflict 'did 'dname
    +        :do-nothing
    +                          :returning 'id))
    +
    +
    +

    +With on-conflict-on-constraint and do-nothing as a separate operator +

    +
    +
    (query (:insert-rows-into 'distributors :columns 'did 'dname
    +                          :values '((10 "Readline GmbH"))
    +                          :on-conflict-on-constraint 'distributors-pkey
    +                          :do-nothing
    +        :returning 'id))
    +
    +
    +

    +With on-conflict constraint with separate :do-nothing keyword and returning +

    +
    +
    (sql (:insert-rows-into 'test :columns 'some-key 'some-val
    +                        :values '(("a" 4) ("b" 6) ("c" 7))
    +                        :on-conflict 'some-key
    +                        :do-nothing
    +      :returning '*))
    +
    +
    +

    +multiple values basic :on-conflict-on-constraint with separate :do-nothing keyword and returning +

    +
    +
    (query (:insert-rows-into 'test :columns 'some-key 'some-val
    +                        :values '(("a" 3) ("b" 6) ("c" 7))
    +                        :on-conflict-on-constraint 'somekey
    +                        :do-nothing
    +        :returning '*))
    +
    +
    +
    +
    +
    +

    Insert-Rows-On-Conflict-Update

    +
    +

    +basic version single row +

    +
    +
    (query (:insert-rows-into 'users
    +        :values '(((:uuid-generate-v4) "Lucie" "Hawkins" "Lucie-Jones@gmail.com"))
    +        :on-conflict-update 'email
    +        :update-set 'first-name 'excluded.first-name 'last-name 'excluded.last-name))
    +
    +
    +

    +Basic version multiple row and specified columns +

    +
    +
    (query (:insert-rows-into 'distributors
    +        :columns 'did 'dname
    +                          :values '((5 "Gizmo Transglobal") (6 "Associated Computing Inc."))
    +                          :on-conflict-update 'did
    +                          :update-set 'dname 'excluded.dname))
    +
    +
    +

    +With where clause +

    +
    +
    (query (:insert-rows-into 'users
    +        :values '(((:uuid-generate-v4) "Lucie" "Hawkins" "Lucie-Jones@gmail.com"))
    +        :on-conflict-update 'email
    +        :update-set 'first-name 'excluded.first-name 'last-name 'excluded.last-name
    +                          :where (:<> 'u.first-name "Lucie")))
    +
    +
    +

    +With an as clause at the table level +

    +
    +
    (query (:insert-rows-into (:as 'users 'u)
    +        :values '(((:uuid-generate-v4) "Lucie" "Jones" "Lucie-Jones@gmail.com"))
    +        :on-conflict-update 'email
    +        :update-set 'first-name 'excluded.first-name 'last-name 'excluded.last-name
    +                          :where (:<> 'u.first-name "Lucie")))
    +
    +
    +

    +With concatenation function in the update-set clause +

    +
    +
    (query (:insert-rows-into (:as 'distributors 'd)
    +        :columns 'did 'dname
    +        :values '((8 "Anvil Distribution"))
    +        :on-conflict-update 'did
    +        :update-set 'dname (:|| 'excluded.dname  " (formerly " 'd.dname ")")
    +        :where (:<> 'd.zipcode "21201")))
    +
    +
    +

    +with on-conflict-on-constraint +

    +
    +
    (query (:insert-rows-into 'test
    +        :columns 'some-key 'some-val
    +        :values '(("a" 5))
    +        :on-conflict-on-constraint 'somekey
    +        :update-set 'some-val 'excluded.some-val))
    +
    +
    +

    +With on-conflict-on-constraint and returning clause +

    +
    +
    (query (:insert-rows-into 'test
    +        :columns 'some-key 'some-val
    +        :values '(("a" 2) ("b" 6) ("c" 7))
    +        :on-conflict-on-constraint 'somekey
    +        :update-set 'some-val 'excluded.some-val
    +        :returning '*))
    +
    +
    +

    +With on-conflict-on-constraint with addition function in the update-set clause +

    +
    +
    (queryl (:insert-rows-into 'test
    +                 :columns 'some-key
    +                 :values '(("a"))
    +                 :on-conflict-on-constraint 'somekey
    +                 :update-set 'some-val (:+ 'test.some-val 1)))
    +
    +
    +

    +With select clause which returns a single row +

    +
    +
    (query (:insert-rows-into 'attendence :columns 'event-id 'client-id 'attend-status
    +        :values '(((:select 'id
    +                    :from 'event
    +                    :where (:= (:lower 'event-dt) "2020-01-11 17:00:00"))
    +                   3
    +                   "No Show"))
    +        :on-conflict-on-constraint 'attendance-pkey
    +        :update-set 'attend-status 'excluded.attend_status))
    +
    +
    +
    +
    + +
    +

    Inserting from an alist

    +
    +

    +Assume that you have a list of alists and you want to insert the data. If the list of alists contain all the columns, then you do not need to specify the columns and simply loop across to get the total lists of values: +

    +
    +
    (let ((alst '(((name . "John") (age . 34)) ((name . "Susan") (age . 37)))))
    +  (query (:insert-rows-into 'table
    +          :values (loop :for x :in alst
    +                        :collect
    +                        (loop :for y :in x
    +                              :collect (cdr y))))))
    +
    +
    +

    +If the alists only contain a subset of the columns, then you would need to specify the columns: +

    +
    +
    (let ((alst '(((name . "John") (age . 34)) ((name . "Susan") (age . 37)))))
    +  (query (:insert-rows-into 'table
    +          :columns 'name 'age
    +          :values (loop :for x :in alst
    +                        :collect
    +                        (loop :for y :in x
    +                              :collect (cdr y))))))
    +
    +
    +
    +
    +
    +

    Inserting from a plist

    +
    +

    +What happens if you want to insert from a plist? +

    + +

    +Assume you have a plist where the keys are interned that you want to insert as a record. Consider the following: +

    +
    +
    (query
    + (sql-compile
    +  (append `(:insert-into ,table :set)
    +          plst)))
    +
    +
    + +

    +That gives you the opportunity to generalize into something like this: +

    +
    +
    (defun insert-db-from-plist (table plst)
    +  "Takes a table and a plist and inserts the plist into the table as a new record."
    +  (when (stringp table)
    +    (setf table (intern (string-upcase table))))
    +     (with-connection (db)
    +                      (query
    +                       (sql-compile
    +                        (append `(:insert-into ,table :set)
    +                                  (loop for x in plst counting x into y collect
    +                                        (if (oddp y)
    +                                            (cond ((symbolp x)
    +                                                   x)
    +                                                  ((stringp x)
    +                                                   (intern (string-upcase x)))
    +                                                  (t nil))
    +                                          x)))))))
    +
    +
    +
    +
    +
    + +
    +

    Intersect

    +
    +

    +Intersect produces a result that contain rows that appear on all the sub-selects. +

    +
    +
      (query (:intersect (:select 'countries.name
    +                            :from 'countries
    +                            :where (:< 'latitude 16.44))
    +                   (:select 'countries.name
    +                            :from 'countries 'regions
    +                            :where (:and (:= 'region-id 'regions.id)
    +                                         (:= 'regions.name "Caribbean")))))
    +
    +(("Aruba") ("Netherlands Antilles") ("Grenada") ("Barbados") ("Trinidad and Tobago"))
    +
    +
    +
    +
    + +
    +

    Intervals

    +
    +

    +See Interval Notes +

    +
    +
    +
    + + \ No newline at end of file diff --git a/doc/s-sql-i.org b/doc/s-sql-i.org new file mode 100644 index 0000000..3e17567 --- /dev/null +++ b/doc/s-sql-i.org @@ -0,0 +1,348 @@ +#+TITLE: S-SQL Examples I +#+OPTIONS: num:nil +#+HTML_HEAD: +#+HTML_HEAD: +#+OPTIONS: ^:nil + +* [[file:s-sql-examples.org][S-SQL Examples Home Page]] +| [[file:s-sql-a.org][A]]| [[file:s-sql-b.org][B]]| [[file:s-sql-c.org][C]]| [[file:s-sql-d.org][D]]| [[file:s-sql-e.org][E]]| [[file:s-sql-f.org][F]]| [[file:s-sql-g.org][G]]| [[file:s-sql-h.org][H]]| [[file:s-sql-i.org][I]]| [[file:s-sql-j.org][J]]| [[file:s-sql-k.org][K]]| [[file:s-sql-l.org][L]]| [[file:s-sql-m.org][M]]| [[file:s-sql-n.org][N]]| [[file:s-sql-o.org][O]]| [[file:s-sql-p.org][P]]| [[file:s-sql-r.org][R]]| [[file:s-sql-s.org][S]]| [[file:s-sql-t.org][T]]| [[file:s-sql-u.org][U]]| [[file:s-sql-v.org][V]]| [[file:s-sql-w.org][W]]| [[file:s-sql-special-characters.org][Special Characters]] | [[file:calling-postgresql-stored-functions.org][Calling Postgresql Stored Functions and Procedures]]| + +* ilike + :PROPERTIES: + :CUSTOM_ID: iloke + :END: +See [[file:s-sql-l.org][s-sql-l (like, ilike, limit)]] + +* In + :PROPERTIES: + :CUSTOM_ID: in + :END: +#+begin_src lisp + (query (:select 'name + :from 'countries + :where (:in 'id + (:set 20 21 23)))) +#+end_src + +* Insert, Insert-into + :PROPERTIES: + :CUSTOM_ID: insert + :END: +** First, without s-sql + :PROPERTIES: + :CUSTOM_ID: sql-insert + :END: +#+begin_src lisp + (query "insert into 'countries values (920, 'Oz', 'Oz Dollars')") +#+end_src + +** With s-sql + :PROPERTIES: + :CUSTOM_ID: s-sql-insert + :END: +There are two ways to use s-sql with basic single row inserts. First, directly setting the columns, using the :set keyword and alternating column names and values. This means that the :insert-into clause expects the arguments to :set to be in multiples of two. Odd arguments will trigger an error. +#+begin_src lisp + (query (:insert-into 'countries :set 'id 920 'name "Oz" + 'currency "Oz Dollars")) +#+end_src +Notice that a list with two items is a single item, not a multiple of two. You can use sql-compile to deal with this. See this example from the mailing list. +#+begin_src lisp + (sql-compile `(:insert-into 'kupci :set ,@(when t (list 'ime "a")))) +#+end_src +The second method, without the :set keyword, uses :select, followed by values. +#+begin_src lisp + (query (:insert-into 'countries (:select "Oz" "Oz Dollars"))) + + (query (:insert-into 'test2 (:select '* :from 'test1))) +#+end_src + +** Returning the Primary Key + :PROPERTIES: + :CUSTOM_ID: returning-primary + :END: +Suppose your table has a serial key of id and you want the insert function to return the newly generated id for that new record. +#+begin_src lisp + (query (:insert-into 'categories :set 'name "test-cat3" :returning 'id) + :single) +#+end_src +The next example shows the same example using parameterized variables. +#+begin_src lisp + (let ((name "test-cat4")) + (query (:insert-into 'categories :set 'name '$1 :returning 'id) + name :single)) +#+end_src +Note: This is a postgresql extension to the standard From the Documentation: + +INSERT conforms to the SQL standard, except that the RETURNING clause is a PostgreSQL extension, as is the ability to use WITH with INSERT, and the ability to specify an alternative action with ON CONFLICT. Also, the case in which a column name list is omitted, but not all the columns are filled from the VALUES clause or query, is disallowed by the standard. + +The SQL standard specifies that OVERRIDING SYSTEM VALUE can only be specified if an identity column that is generated always exists. PostgreSQL allows the clause in any case and ignores it if it is not applicable. +With DAOs +** Insert-DAO +Postmodern has an update-dao and an insert-dao function. You could check and see if the dao that you are currently dealing with has its primary key set (in which case you are editing an existing object and need to use update-dao. If not, then you dealing with a brand new object and will need to set the primary key and use the insert-dao method, using something like this: +#+begin_src lisp + (if (id item) (postmodern:update-dao item) + (progn (setf (id item) (get-next-id class-name)) + (postmodern:insert-dao item))) +#+end_src +However, you could also just use upsert. +#+begin_src lisp + (postmodern:upsert-dao item) +#+end_src + +** Multiple Row Inserts + :PROPERTIES: + :CUSTOM_ID: multiple-row-inserts + :END: +You can use s-sql to generate INSERT INTO clauses with multiple rows, e.g. "INSERT INTO \"table\" (a, b) VALUES (10, 20), (30, 40)". (This ability does not yet exist with respect to inserting multiple daos. + +First, without specifying columns: +#+begin_src lisp + (query (:insert-rows-into 'my-table :values '((42 "foobar") (23 "foobaz")))) +#+end_src +Now with specifying columns: +#+begin_src lisp + (query (:insert-rows-into 'table + :columns 'a 'b + :values '((10 20) (30 40)))) + + (query (:insert-rows-into 'cd.facilities + :columns 'facid 'name 'membercost 'guestcost 'initialoutlay 'monthlymaintenance + :values '((9 "Spa" 20 30 100000 800) + (10 "Squash Court 2" 3.5 17.5 5000 80)))) +#+end_src +Using a select statement: +#+begin_src lisp + (query (:insert-rows-into 'cd.facilities + :columns 'facid 'name 'membercost 'guestcost 'initialoutlay 'monthlymaintenance + :values '(((:select (:+ (:select (:max 'facid) + :from 'cd.facilities) + 1)) + "Spa" 20 30 100000 800)))) +#+end_src +Overriding System Values: +#+begin_src lisp + (query (:insert-rows-into 'table1 + :columns 'c1 'c2 + :overriding-system-value + :values '((1 "a") (2 "b")))) +#+end_src +** Insert-Rows-On-Conflict-Do-Nothing + :PROPERTIES: + :CUSTOM_ID: Insert-Rows-On-Conflict-Do-Nothing + :END: +Inserting rows with on conflict do nothing +#+begin_src lisp + (query (:insert-rows-into 'distributors + :columns 'did 'dname + :values '((7 "Readline GmbH")) + :on-conflict-do-nothing)) +#+end_src +:on-conflict with separate :do-nothing keyword +#+begin_src lisp + (query (:insert-rows-into 'test :columns 'some-key 'some-val + :values '(("a" 5) ("b" 6) ("c" 7)) + :on-conflict 'some-key + :do-nothing)) +#+end_src +With where condition +#+begin_src lisp + (query (:insert-rows-into 'distributors + :columns 'did 'dname + :values '((10 "Conrad International")) + :on-conflict 'did + :do-nothing + :where 'is-active)) +#+end_src +With returning +#+begin_src lisp + (query (:insert-rows-into 'distributors + :columns 'did 'dname + :values '((8 "Readline GmbH")) + :on-conflict 'did 'dname + :do-nothing + :returning 'id)) +#+end_src +With on-conflict-on-constraint and do-nothing as a separate operator +#+begin_src lisp + (query (:insert-rows-into 'distributors :columns 'did 'dname + :values '((10 "Readline GmbH")) + :on-conflict-on-constraint 'distributors-pkey + :do-nothing + :returning 'id)) +#+end_src +With on-conflict constraint with separate :do-nothing keyword and returning +#+begin_src lisp + (sql (:insert-rows-into 'test :columns 'some-key 'some-val + :values '(("a" 4) ("b" 6) ("c" 7)) + :on-conflict 'some-key + :do-nothing + :returning '*)) +#+end_src +multiple values basic :on-conflict-on-constraint with separate :do-nothing keyword and returning +#+begin_src lisp + (query (:insert-rows-into 'test :columns 'some-key 'some-val + :values '(("a" 3) ("b" 6) ("c" 7)) + :on-conflict-on-constraint 'somekey + :do-nothing + :returning '*)) +#+end_src +** Insert-Rows-On-Conflict-Update + :PROPERTIES: + :CUSTOM_ID: Insert-Rows-On-Conflict-update + :END: +basic version single row +#+begin_src lisp + (query (:insert-rows-into 'users + :values '(((:uuid-generate-v4) "Lucie" "Hawkins" "Lucie-Jones@gmail.com")) + :on-conflict-update 'email + :update-set 'first-name 'excluded.first-name 'last-name 'excluded.last-name)) +#+end_src +Basic version multiple row and specified columns +#+begin_src lisp + (query (:insert-rows-into 'distributors + :columns 'did 'dname + :values '((5 "Gizmo Transglobal") (6 "Associated Computing Inc.")) + :on-conflict-update 'did + :update-set 'dname 'excluded.dname)) +#+end_src +With where clause +#+begin_src lisp + (query (:insert-rows-into 'users + :values '(((:uuid-generate-v4) "Lucie" "Hawkins" "Lucie-Jones@gmail.com")) + :on-conflict-update 'email + :update-set 'first-name 'excluded.first-name 'last-name 'excluded.last-name + :where (:<> 'u.first-name "Lucie"))) +#+end_src +With an as clause at the table level +#+begin_src lisp + (query (:insert-rows-into (:as 'users 'u) + :values '(((:uuid-generate-v4) "Lucie" "Jones" "Lucie-Jones@gmail.com")) + :on-conflict-update 'email + :update-set 'first-name 'excluded.first-name 'last-name 'excluded.last-name + :where (:<> 'u.first-name "Lucie"))) +#+end_src +With concatenation function in the update-set clause +#+begin_src lisp + (query (:insert-rows-into (:as 'distributors 'd) + :columns 'did 'dname + :values '((8 "Anvil Distribution")) + :on-conflict-update 'did + :update-set 'dname (:|| 'excluded.dname " (formerly " 'd.dname ")") + :where (:<> 'd.zipcode "21201"))) +#+end_src +with on-conflict-on-constraint +#+begin_src lisp + (query (:insert-rows-into 'test + :columns 'some-key 'some-val + :values '(("a" 5)) + :on-conflict-on-constraint 'somekey + :update-set 'some-val 'excluded.some-val)) +#+end_src +With on-conflict-on-constraint and returning clause +#+begin_src lisp + (query (:insert-rows-into 'test + :columns 'some-key 'some-val + :values '(("a" 2) ("b" 6) ("c" 7)) + :on-conflict-on-constraint 'somekey + :update-set 'some-val 'excluded.some-val + :returning '*)) +#+end_src +With on-conflict-on-constraint with addition function in the update-set clause +#+begin_src lisp + (queryl (:insert-rows-into 'test + :columns 'some-key + :values '(("a")) + :on-conflict-on-constraint 'somekey + :update-set 'some-val (:+ 'test.some-val 1))) +#+end_src +With select clause which returns a single row +#+begin_src lisp + (query (:insert-rows-into 'attendence :columns 'event-id 'client-id 'attend-status + :values '(((:select 'id + :from 'event + :where (:= (:lower 'event-dt) "2020-01-11 17:00:00")) + 3 + "No Show")) + :on-conflict-on-constraint 'attendance-pkey + :update-set 'attend-status 'excluded.attend_status)) +#+end_src + +** Inserting from an alist + :PROPERTIES: + :CUSTOM_ID: insert-from-alist + :END: +Assume that you have a list of alists and you want to insert the data. If the list of alists contain all the columns, then you do not need to specify the columns and simply loop across to get the total lists of values: +#+begin_src lisp + (let ((alst '(((name . "John") (age . 34)) ((name . "Susan") (age . 37))))) + (query (:insert-rows-into 'table + :values (loop :for x :in alst + :collect + (loop :for y :in x + :collect (cdr y)))))) +#+end_src +If the alists only contain a subset of the columns, then you would need to specify the columns: +#+begin_src lisp + (let ((alst '(((name . "John") (age . 34)) ((name . "Susan") (age . 37))))) + (query (:insert-rows-into 'table + :columns 'name 'age + :values (loop :for x :in alst + :collect + (loop :for y :in x + :collect (cdr y)))))) +#+end_src +** Inserting from a plist + :PROPERTIES: + :CUSTOM_ID: insert-from-plist + :END: +What happens if you want to insert from a plist? + +Assume you have a plist where the keys are interned that you want to insert as a record. Consider the following: +#+begin_src lisp + (query + (sql-compile + (append `(:insert-into ,table :set) + plst))) +#+end_src + +That gives you the opportunity to generalize into something like this: +#+begin_src lisp +(defun insert-db-from-plist (table plst) + "Takes a table and a plist and inserts the plist into the table as a new record." + (when (stringp table) + (setf table (intern (string-upcase table)))) + (with-connection (db) + (query + (sql-compile + (append `(:insert-into ,table :set) + (loop for x in plst counting x into y collect + (if (oddp y) + (cond ((symbolp x) + x) + ((stringp x) + (intern (string-upcase x))) + (t nil)) + x))))))) +#+end_src + +* Intersect + :PROPERTIES: + :CUSTOM_ID: intersect + :END: +Intersect produces a result that contain rows that appear on all the sub-selects. +#+begin_src lisp + (query (:intersect (:select 'countries.name + :from 'countries + :where (:< 'latitude 16.44)) + (:select 'countries.name + :from 'countries 'regions + :where (:and (:= 'region-id 'regions.id) + (:= 'regions.name "Caribbean"))))) + +(("Aruba") ("Netherlands Antilles") ("Grenada") ("Barbados") ("Trinidad and Tobago")) +#+end_src + +* Intervals + :PROPERTIES: + :CUSTOM_ID: intervals + :END: +See [[file:interval-notes.html][Interval Notes]] diff --git a/doc/s-sql-j.html b/doc/s-sql-j.html new file mode 100644 index 0000000..43068ec --- /dev/null +++ b/doc/s-sql-j.html @@ -0,0 +1,478 @@ + + + + + + +S-SQL Examples J + + + + + + + +
    +
    +

    S-SQL Examples J

    +
    + +
    +

    S-SQL Examples Home Page

    +
    + + + +++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ + + + + + + + + + + + + + + + + + + + + + + + + + + + + +
    ABCDEFGHIJKLMNOPRSTUVWSpecial CharactersCalling Postgresql Stored Functions and Procedures
    +
    +
    + + +
    +

    Joins

    +
    +

    +A long discussion of joins can be found here: http://www.gplivna.eu/papers/sql_join_types.htm (Oracle centric, but still useful). The postgresql documentation pages can be found here: http://www.postgresql.org/docs/9.3/static/sql-select.html#SQL-FROM +

    +
    + +
    +

    Cross Join

    +
    +

    +From the postgresql documentation: "For every possible combination of rows from T1 and T2 (i.e., a Cartesian product), the joined table will contain a row consisting of all columns in T1 followed by all columns in T2. If the tables have N and M rows respectively, the joined table will have N * M rows." +

    +
    +
    (query (:select '* from 'employee
    +        :cross-join 'compensation))
    +
    +
    +
    +
    + +
    +

    Inner Join

    +
    +

    +An inner join looks at two tables and creates a new result consisting of the selected elements in the rows from the two tables that match the specified conditions. You can simplistically think of it as the intersection of the two sets. In reality, it is creating a new set consisting of certain elements of the intersecting rows. An inner join is the default and need not be specified. +

    + +

    +A sample of standard sql on an inner join could look like this: +

    +
    +
    (SELECT foo, bar, baz
    +        FROM (SELECT foo FROM x WHERE some-condition-here) AS tmp1
    +        INNER JOIN
    +          (SELECT bar FROM x WHERE some-condition-here) AS tmp2
    +        ON (tmp1.id = tmp2.id)
    +        INNER JOIN
    +          (SELECT baz FROM x WHERE some-condition-here) AS tmp3
    +        ON (tmp2.id = tmp3.id))
    +
    +
    + +

    +The same query could be expressed in s-sql as: +

    +
    +
    (query (:select 'foo 'bar 'baz
    +        :from (:as
    +               (:select 'foo
    +                :from 'x
    +                :where 'x)
    +               'tmp1)
    +        :inner-join (:as
    +                     (:select 'bar
    +                      :from 'x
    +                      :where 'x)
    +                     'tmp2)
    +        :on (:= 'tmp1.id 'tmp2.id)
    +        :inner-join (:as
    +                     (:select 'baz
    +                      :from 'x
    +                      :where 'x)
    +                     'tmp3)
    +        :on (:= 'tmp2.id 'tmp3.id)))
    +
    +
    +
    + +

    +The normal pre-ansi shorthand example, using our countries and regions tables would look like this: +

    +
    +
    (query (:select 'countries.name
    +                :from 'countries 'regions
    +                :where (:and (:= 'countries.region-id 'regions.id)
    +                             (:= 'regions.name "North America"))))
    +
    +(("US") ("Canada") ("Mexico") ("Bermuda"))
    +
    +
    +
    + +

    +The full portable ansi version, using inner join would look like this. +

    +
    +
    (query (:select 'tmp1.name
    +        :from (:as (:select 'name 'region-id
    +                            :from 'countries)
    +                   'tmp1)
    +                :inner-join (:as (:select 'id
    +                                  :from 'regions
    +                                  :where (:= 'name "North America"))
    +                                 'tmp2)
    +        :on (:= 'tmp1.region-id 'tmp2.id)))
    +
    +(("US") ("Canada") ("Mexico") ("Bermuda"))
    +
    +
    +
    + +

    +Some people argue that specifying the inner join allows separation of join criteria and, therefore is more readable. I leave that to you and your coding style. +

    +
    +
    + +
    +

    Outer Join

    +
    +

    +An outer join not only generates an inner join, it also joins the rows from one table that matches the conditions and adds null values for the joined columns from the second table (which obviously did not match the condition.) Under Postgresql, a "left join", "right join" or "full join" all imply an outer join. +

    + +

    +A left join (or left outer join) looks at two tables, keeps the matched rows from both and the unmatched rows from the left table and drops the unmatched rows from the right table. A right outer join keeps the matched rows, the unmatched rows from the right table and drops the unmatched rows from the left table. A full outer join includes the rows that match from each table individually, with null values for the missing matching columns. +

    +
    +
    + +
    +

    Left Join

    +
    +

    +Example: Here we assume two tables. A countries table and a many-to-many linking table named countries-topics. (There is an implicit third table named topics.) We are looking for records from the countries table which do not have a match in the countries-topics table. In other words, where do we have a note, but not matched it to a topic? +

    +
    +
    (defun notes-with-no-topics ()
    +  (query (:order-by
    +          (:select 'countries.id 'countries.name
    +                             :distinct
    +                             :from 'countries
    +                             :left-join 'countries-topics
    +                             :on (:= 'countries.id 'countries-topics.country-id)
    +                             :where (:is-null 'countries-topics.country-id))
    +                    'countries.id)))
    +
    +
    +
    + +

    +Here is a somewhat contrived example using our countries and regions table. We want to get the names of all the regions and also return the country names in one specified region. Assume that we only want the names of the countries in Central America, which happens to have a region-id of 3. +

    +
    +
    (query (:select 'tmp2.name 'tmp1.name
    +                :from (:as (:select 'id 'name
    +                                    :from 'regions)
    +                           'tmp2)
    +                :left-join (:as (:select 'name 'region-id
    +                                         :from 'countries
    +                                         :where (:= 'region-id 3))
    +                                'tmp1)
    +                :on (:= 'tmp1.region-id 'tmp2.id)))
    +
    +(("Central America" "Panama") ("Central America" "Costa Rica") ("Central America" "Guatemala")
    + ("Central America" "Nicaragua") ("Central America" "Belize") ("Central America" "El Salvador")
    + ("Western Africa" :NULL) ("Eastern Europe" :NULL) ("APAC" :NULL) ("Southern Europe" :NULL)
    + ("Caribbean" :NULL)  ("LATAM" :NULL) ("Northern Africa" :NULL) ("Eastern Africa" :NULL)
    + ("Asia" :NULL)  ("US" :NULL)  ("Middle East" :NULL)  ("South East Asia" :NULL)
    + ("Oceania" :NULL)  ("Northern Europe" :NULL) ("Emerging" :NULL) ("All" :NULL)
    + ("Central Asia" :NULL) ("Eastern Asia" :NULL) ("North America" :NULL) ("EMEA" :NULL)
    + ("Middle Africa" :NULL) ("Western Europe" :NULL) ("Africa" :NULL) ("South Central Asia" :NULL)
    + ("Southern Africa" :NULL)  ("Canada" :NULL) ("Pacific" :NULL) ("South America" :NULL))
    +
    +
    +
    +
    +
    +
    + + \ No newline at end of file diff --git a/doc/s-sql-j.org b/doc/s-sql-j.org new file mode 100644 index 0000000..6ddd695 --- /dev/null +++ b/doc/s-sql-j.org @@ -0,0 +1,144 @@ +#+TITLE: S-SQL Examples J +#+OPTIONS: num:nil +#+HTML_HEAD: +#+HTML_HEAD: +#+OPTIONS: ^:nil + +* [[file:s-sql-examples.org][S-SQL Examples Home Page]] +| [[file:s-sql-a.org][A]]| [[file:s-sql-b.org][B]]| [[file:s-sql-c.org][C]]| [[file:s-sql-d.org][D]]| [[file:s-sql-e.org][E]]| [[file:s-sql-f.org][F]]| [[file:s-sql-g.org][G]]| [[file:s-sql-h.org][H]]| [[file:s-sql-i.org][I]]| [[file:s-sql-j.org][J]]| [[file:s-sql-k.org][K]]| [[file:s-sql-l.org][L]]| [[file:s-sql-m.org][M]]| [[file:s-sql-n.org][N]]| [[file:s-sql-o.org][O]]| [[file:s-sql-p.org][P]]| [[file:s-sql-r.org][R]]| [[file:s-sql-s.org][S]]| [[file:s-sql-t.org][T]]| [[file:s-sql-u.org][U]]| [[file:s-sql-v.org][V]]| [[file:s-sql-w.org][W]]| [[file:s-sql-special-characters.org][Special Characters]] | [[file:calling-postgresql-stored-functions.org][Calling Postgresql Stored Functions and Procedures]]| + + +* Joins + :PROPERTIES: + :CUSTOM_ID: joins + :END: +A long discussion of joins can be found here: http://www.gplivna.eu/papers/sql_join_types.htm (Oracle centric, but still useful). The postgresql documentation pages can be found here: http://www.postgresql.org/docs/9.3/static/sql-select.html#SQL-FROM + +** Cross Join + :PROPERTIES: + :CUSTOM_ID: cross-join + :END: +From the postgresql documentation: "For every possible combination of rows from T1 and T2 (i.e., a Cartesian product), the joined table will contain a row consisting of all columns in T1 followed by all columns in T2. If the tables have N and M rows respectively, the joined table will have N * M rows." +#+begin_src lisp + (query (:select '* from 'employee + :cross-join 'compensation)) +#+end_src + +** Inner Join + :PROPERTIES: + :CUSTOM_ID: inner-join + :END: +An inner join looks at two tables and creates a new result consisting of the selected elements in the rows from the two tables that match the specified conditions. You can simplistically think of it as the intersection of the two sets. In reality, it is creating a new set consisting of certain elements of the intersecting rows. An inner join is the default and need not be specified. + +A sample of standard sql on an inner join could look like this: +#+begin_src sql +(SELECT foo, bar, baz + FROM (SELECT foo FROM x WHERE some-condition-here) AS tmp1 + INNER JOIN + (SELECT bar FROM x WHERE some-condition-here) AS tmp2 + ON (tmp1.id = tmp2.id) + INNER JOIN + (SELECT baz FROM x WHERE some-condition-here) AS tmp3 + ON (tmp2.id = tmp3.id)) +#+end_src + +The same query could be expressed in s-sql as: +#+begin_src lisp + (query (:select 'foo 'bar 'baz + :from (:as + (:select 'foo + :from 'x + :where 'x) + 'tmp1) + :inner-join (:as + (:select 'bar + :from 'x + :where 'x) + 'tmp2) + :on (:= 'tmp1.id 'tmp2.id) + :inner-join (:as + (:select 'baz + :from 'x + :where 'x) + 'tmp3) + :on (:= 'tmp2.id 'tmp3.id))) + +#+end_src + +The normal pre-ansi shorthand example, using our countries and regions tables would look like this: +#+begin_src lisp +(query (:select 'countries.name + :from 'countries 'regions + :where (:and (:= 'countries.region-id 'regions.id) + (:= 'regions.name "North America")))) + +(("US") ("Canada") ("Mexico") ("Bermuda")) + +#+end_src + + The full portable ansi version, using inner join would look like this. +#+begin_src lisp + (query (:select 'tmp1.name + :from (:as (:select 'name 'region-id + :from 'countries) + 'tmp1) + :inner-join (:as (:select 'id + :from 'regions + :where (:= 'name "North America")) + 'tmp2) + :on (:= 'tmp1.region-id 'tmp2.id))) + + (("US") ("Canada") ("Mexico") ("Bermuda")) + +#+end_src + +Some people argue that specifying the inner join allows separation of join criteria and, therefore is more readable. I leave that to you and your coding style. + +** Outer Join + :PROPERTIES: + :CUSTOM_ID: outer-join + :END: +An outer join not only generates an inner join, it also joins the rows from one table that matches the conditions and adds null values for the joined columns from the second table (which obviously did not match the condition.) Under Postgresql, a "left join", "right join" or "full join" all imply an outer join. + +A left join (or left outer join) looks at two tables, keeps the matched rows from both and the unmatched rows from the left table and drops the unmatched rows from the right table. A right outer join keeps the matched rows, the unmatched rows from the right table and drops the unmatched rows from the left table. A full outer join includes the rows that match from each table individually, with null values for the missing matching columns. + +** Left Join + :PROPERTIES: + :CUSTOM_ID: left-join + :END: +Example: Here we assume two tables. A countries table and a many-to-many linking table named countries-topics. (There is an implicit third table named topics.) We are looking for records from the countries table which do not have a match in the countries-topics table. In other words, where do we have a note, but not matched it to a topic? +#+begin_src lisp + (defun notes-with-no-topics () + (query (:order-by + (:select 'countries.id 'countries.name + :distinct + :from 'countries + :left-join 'countries-topics + :on (:= 'countries.id 'countries-topics.country-id) + :where (:is-null 'countries-topics.country-id)) + 'countries.id))) + +#+end_src + +Here is a somewhat contrived example using our countries and regions table. We want to get the names of all the regions and also return the country names in one specified region. Assume that we only want the names of the countries in Central America, which happens to have a region-id of 3. +#+begin_src lisp +(query (:select 'tmp2.name 'tmp1.name + :from (:as (:select 'id 'name + :from 'regions) + 'tmp2) + :left-join (:as (:select 'name 'region-id + :from 'countries + :where (:= 'region-id 3)) + 'tmp1) + :on (:= 'tmp1.region-id 'tmp2.id))) + +(("Central America" "Panama") ("Central America" "Costa Rica") ("Central America" "Guatemala") + ("Central America" "Nicaragua") ("Central America" "Belize") ("Central America" "El Salvador") + ("Western Africa" :NULL) ("Eastern Europe" :NULL) ("APAC" :NULL) ("Southern Europe" :NULL) + ("Caribbean" :NULL) ("LATAM" :NULL) ("Northern Africa" :NULL) ("Eastern Africa" :NULL) + ("Asia" :NULL) ("US" :NULL) ("Middle East" :NULL) ("South East Asia" :NULL) + ("Oceania" :NULL) ("Northern Europe" :NULL) ("Emerging" :NULL) ("All" :NULL) + ("Central Asia" :NULL) ("Eastern Asia" :NULL) ("North America" :NULL) ("EMEA" :NULL) + ("Middle Africa" :NULL) ("Western Europe" :NULL) ("Africa" :NULL) ("South Central Asia" :NULL) + ("Southern Africa" :NULL) ("Canada" :NULL) ("Pacific" :NULL) ("South America" :NULL)) +#+end_src diff --git a/doc/s-sql-l.html b/doc/s-sql-l.html new file mode 100644 index 0000000..79e7d4d --- /dev/null +++ b/doc/s-sql-l.html @@ -0,0 +1,511 @@ + + + + + + +S-SQL Examples L + + + + + + + +
    +
    +

    S-SQL Examples L

    +
    + +
    +

    S-SQL Examples Home Page

    +
    + + + +++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ + + + + + + + + + + + + + + + + + + + + + + + + + + + + +
    ABCDEFGHIJKLMNOPRSTUVWSpecial CharactersCalling Postgresql Stored Functions and Procedures
    +
    +
    + +
    +

    Lateral

    +
    +

    +Basically, the lateral keyword allows access to columns after the from statement and use them earlier in the query. Here is a sample vanilla sql query using lateral, borrowed from https://popsql.com/learn-sql/postgresql/how-to-use-lateral-joins-in-postgresql#data-set +

    +
    +
    (query
    + "select
    +    pledged_usd,
    +    avg_pledge_usd,
    +    amt_from_goal,
    +    duration,
    +    (usd_from_goal / duration) as usd_needed_daily
    + from kickstarter_data,
    +    lateral (select pledged / fx_rate as pledged_usd) pu
    +    lateral (select pledged_usd / backers_count as avg_pledge_usd) apu
    +    lateral (select goal / fx_rate as goal_usd) gu
    +    lateral (select goal_usd - pledged_usd as usd_from_goal) ufg
    +    lateral (select (deadline - launched_at)/86400.00 as duration) dr;")
    +
    +
    +

    +And now how it would be written in s-sql +

    +
    +
    (query
    + (:select 'pledged-usd 'avg-pledge-usd 'amt-from-goal 'duration
    +          (:as (:/ 'usd-from-goal 'duration) 'usd-needed-daily)
    +          :from 'kickstarter-data
    +          :lateral (:as (:select (:as (:/ 'pledged 'fx-rate)
    +                                      'pledged-usd))
    +                        'pu)
    +          :lateral (:as (:select (:as (:/ 'pledged-usd 'backers-count)
    +                                      'avg-pledge-usd))
    +                        'apu)
    +          :lateral (:as (:select (:as (:/ 'goal 'fx-rate)
    +                                      'goal-usd))
    +                        'gu)
    +          :lateral (:as (:select (:as (:- 'goal-usd 'pledged-usd)
    +                                      'usd-from-goal))
    +                        'ufg)
    +          :lateral (:as (:select (:as (:/ (:- 'deadline 'launched-at) 86400.00)
    +                                      'duration))
    +                        'dr)))
    +
    +
    +

    +Here is an example with :join-lateral +

    +
    +
    (query
    +   (:select '*
    +    :from (:as 'tags 't1)
    +    :join-lateral (:as
    +                   (:fetch
    +                    (:order-by
    +                     (:select 'm.*
    +                      :from (:as 'movies 'm)
    +                      :where (:= 'm.tag-id 't1.id))
    +                     (:desc 'm.created-at))
    +                    2)
    +                   'e1)
    +    :on (:= 1 1)))
    +
    +
    +

    +This one has an :inner-join-lateral +

    +
    +
    (query
    +      (:select '*
    +       :from (:as 'tags 't1)
    +       :inner-join-lateral (:as
    +                            (:fetch
    +                             (:order-by
    +                              (:select 'm.*
    +                               :from (:as 'movies 'm)
    +                               :where (:= 'm.tag-id 't1.id))
    +                              (:desc 'm.created-at))
    +                             2)
    +                            'e1)
    +       :on 't))
    +
    +
    +

    +A :cross-join-lateral +

    +
    +
    (query
    +   (:select '*
    +    :from (:as 'tags 't1)
    +    :cross-join-lateral (:as
    +                         (:fetch
    +                          (:order-by
    +                           (:select 'm.*
    +                            :from (:as 'movies 'm)
    +                            :where (:= 'm.tag-id 't1.id))
    +                           (:desc 'm.created-at))
    +                          2)
    +                         'e1)))
    +
    +  (query
    +   (:select 'geo.zipcode 'geo.state 'movie.name
    +    :from 'geo
    +    :cross-join-lateral
    +    (:as
    +     (:limit
    +      (:order-by
    +       (:select 'movie-name
    +        :from 'streams
    +        :where (:= 'geo.zipcode 'streams.zipcode))
    +       (:desc 'streams.country))
    +      5)
    +     (:movie 'name))))
    +
    +
    +

    +And a :left-join-lateral +

    +
    +
    (query
    +   (:select 'p.* (:as 'dads.id 'dad-id) (:as 'moms.id 'mom-id)
    +    :from (:as 'people 'p)
    +    :left-join-lateral (:as (:select '*
    +                             :from 'people
    +                             :where (:and (:= 'gender "m")
    +                                          (:= 'surname-1 'p.surname-1)
    +                                          (:<> 'pack-id 'p.pack-id)))
    +                            'dads)
    +    :on 't
    +    :left-join-lateral (:as (:select '*
    +                             :from 'people
    +                             :where (:and (:= 'gender "f")
    +                                          (:= 'surname-1 'p.surname-2)
    +                                          (:<> 'pack-id 'p.pack-id)
    +                                          (:<> 'pack-id 'dads.pack-id)))
    +                            'moms)
    +    :on 't))
    +
    +
    +
    +
    +
    +

    Like, ilike Example

    +
    +

    +The sql like operator provides a little bit of fuzzy string matching in a search. The following is a simple example using the sql like operator in s-sql. +

    +
    +
    (query (:select 'id 'name
    +                :from 'countries
    +                :where (:like 'name "%New%")))
    +
    +((103 "New Caledonia") (58 "New Zealand") (108 "Papua New Guinea"))
    +
    +
    +
    + +

    +The sql ilike operator provides the same thing, but on a case insensitive basis. The following is a simple example using the sql ilike operator in s-sql. +

    +
    +
    (query (:select 'id 'name
    +                :from 'countries
    +                :where (:like 'name "%NEW%")))
    +
    +((103 "New Caledonia") (58 "New Zealand") (108 "Papua New Guinea"))
    +
    +
    +
    +
    +
    + +
    +

    Limit and offset

    +
    +

    +Note that :limit has 2 possible parameters, the limit and the offset. Note that the :order-by and :limit forms are wrapped around the :select form. The only difference between the two queries is the offset parameter. +

    +
    +
    (let ((list-limit 2)
    +      (offset 0))
    +  (query
    +   (:limit
    +    (:order-by
    +     (:select 'countries.id 'countries.name
    +              :from 'countries)
    +     'name)
    +    '$1 '$2)
    +   list-limit offset))
    +
    +((82 "Afghanistan") (130 "Albania"))
    +
    +(let ((list-limit 2) (offset 2))
    +  (query
    +   (:limit
    +    (:order-by
    +     (:select 'countries.id 'countries.name
    +              :from 'countries)
    +     'name)
    +    '$1 '$2)
    +   list-limit offset))
    +
    +((140 "Algeria") (34 "All"))
    +
    +
    +
    +
    +
    + + \ No newline at end of file diff --git a/doc/s-sql-l.org b/doc/s-sql-l.org new file mode 100644 index 0000000..d6fc184 --- /dev/null +++ b/doc/s-sql-l.org @@ -0,0 +1,188 @@ +#+TITLE: S-SQL Examples L +#+OPTIONS: num:nil +#+HTML_HEAD: +#+HTML_HEAD: +#+OPTIONS: ^:nil + +* [[file:s-sql-examples.org][S-SQL Examples Home Page]] +| [[file:s-sql-a.org][A]]| [[file:s-sql-b.org][B]]| [[file:s-sql-c.org][C]]| [[file:s-sql-d.org][D]]| [[file:s-sql-e.org][E]]| [[file:s-sql-f.org][F]]| [[file:s-sql-g.org][G]]| [[file:s-sql-h.org][H]]| [[file:s-sql-i.org][I]]| [[file:s-sql-j.org][J]]| [[file:s-sql-k.org][K]]| [[file:s-sql-l.org][L]]| [[file:s-sql-m.org][M]]| [[file:s-sql-n.org][N]]| [[file:s-sql-o.org][O]]| [[file:s-sql-p.org][P]]| [[file:s-sql-r.org][R]]| [[file:s-sql-s.org][S]]| [[file:s-sql-t.org][T]]| [[file:s-sql-u.org][U]]| [[file:s-sql-v.org][V]]| [[file:s-sql-w.org][W]]| [[file:s-sql-special-characters.org][Special Characters]] | [[file:calling-postgresql-stored-functions.org][Calling Postgresql Stored Functions and Procedures]]| + +* Lateral + :PROPERTIES: + :CUSTOM_ID: lateral + :END: +Basically, the lateral keyword allows access to columns after the from statement and use them earlier in the query. Here is a sample vanilla sql query using lateral, borrowed from [[https://popsql.com/learn-sql/postgresql/how-to-use-lateral-joins-in-postgresql#data-set][https://popsql.com/learn-sql/postgresql/how-to-use-lateral-joins-in-postgresql#data-set]] +#+begin_src lisp + (query + "select + pledged_usd, + avg_pledge_usd, + amt_from_goal, + duration, + (usd_from_goal / duration) as usd_needed_daily + from kickstarter_data, + lateral (select pledged / fx_rate as pledged_usd) pu + lateral (select pledged_usd / backers_count as avg_pledge_usd) apu + lateral (select goal / fx_rate as goal_usd) gu + lateral (select goal_usd - pledged_usd as usd_from_goal) ufg + lateral (select (deadline - launched_at)/86400.00 as duration) dr;") +#+end_src +And now how it would be written in s-sql +#+begin_src lisp + (query + (:select 'pledged-usd 'avg-pledge-usd 'amt-from-goal 'duration + (:as (:/ 'usd-from-goal 'duration) 'usd-needed-daily) + :from 'kickstarter-data + :lateral (:as (:select (:as (:/ 'pledged 'fx-rate) + 'pledged-usd)) + 'pu) + :lateral (:as (:select (:as (:/ 'pledged-usd 'backers-count) + 'avg-pledge-usd)) + 'apu) + :lateral (:as (:select (:as (:/ 'goal 'fx-rate) + 'goal-usd)) + 'gu) + :lateral (:as (:select (:as (:- 'goal-usd 'pledged-usd) + 'usd-from-goal)) + 'ufg) + :lateral (:as (:select (:as (:/ (:- 'deadline 'launched-at) 86400.00) + 'duration)) + 'dr))) +#+end_src +Here is an example with :join-lateral +#+begin_src lisp + (query + (:select '* + :from (:as 'tags 't1) + :join-lateral (:as + (:fetch + (:order-by + (:select 'm.* + :from (:as 'movies 'm) + :where (:= 'm.tag-id 't1.id)) + (:desc 'm.created-at)) + 2) + 'e1) + :on (:= 1 1))) +#+end_src +This one has an :inner-join-lateral +#+begin_src lisp + (query + (:select '* + :from (:as 'tags 't1) + :inner-join-lateral (:as + (:fetch + (:order-by + (:select 'm.* + :from (:as 'movies 'm) + :where (:= 'm.tag-id 't1.id)) + (:desc 'm.created-at)) + 2) + 'e1) + :on 't)) +#+end_src +A :cross-join-lateral +#+begin_src lisp + (query + (:select '* + :from (:as 'tags 't1) + :cross-join-lateral (:as + (:fetch + (:order-by + (:select 'm.* + :from (:as 'movies 'm) + :where (:= 'm.tag-id 't1.id)) + (:desc 'm.created-at)) + 2) + 'e1))) + + (query + (:select 'geo.zipcode 'geo.state 'movie.name + :from 'geo + :cross-join-lateral + (:as + (:limit + (:order-by + (:select 'movie-name + :from 'streams + :where (:= 'geo.zipcode 'streams.zipcode)) + (:desc 'streams.country)) + 5) + (:movie 'name)))) + #+end_src + And a :left-join-lateral + #+begin_src lisp + (query + (:select 'p.* (:as 'dads.id 'dad-id) (:as 'moms.id 'mom-id) + :from (:as 'people 'p) + :left-join-lateral (:as (:select '* + :from 'people + :where (:and (:= 'gender "m") + (:= 'surname-1 'p.surname-1) + (:<> 'pack-id 'p.pack-id))) + 'dads) + :on 't + :left-join-lateral (:as (:select '* + :from 'people + :where (:and (:= 'gender "f") + (:= 'surname-1 'p.surname-2) + (:<> 'pack-id 'p.pack-id) + (:<> 'pack-id 'dads.pack-id))) + 'moms) + :on 't)) +#+end_src +* Like, ilike Example + :PROPERTIES: + :CUSTOM_ID: like + :END: +The sql like operator provides a little bit of fuzzy string matching in a search. The following is a simple example using the sql like operator in s-sql. +#+begin_src lisp +(query (:select 'id 'name + :from 'countries + :where (:like 'name "%New%"))) + +((103 "New Caledonia") (58 "New Zealand") (108 "Papua New Guinea")) + +#+end_src + +The sql ilike operator provides the same thing, but on a case insensitive basis. The following is a simple example using the sql ilike operator in s-sql. +#+begin_src lisp +(query (:select 'id 'name + :from 'countries + :where (:like 'name "%NEW%"))) + +((103 "New Caledonia") (58 "New Zealand") (108 "Papua New Guinea")) + +#+end_src + +* Limit and offset + :PROPERTIES: + :CUSTOM_ID: limit + :END: +Note that :limit has 2 possible parameters, the limit and the offset. Note that the :order-by and :limit forms are wrapped around the :select form. The only difference between the two queries is the offset parameter. +#+begin_src lisp + (let ((list-limit 2) + (offset 0)) + (query + (:limit + (:order-by + (:select 'countries.id 'countries.name + :from 'countries) + 'name) + '$1 '$2) + list-limit offset)) + + ((82 "Afghanistan") (130 "Albania")) + + (let ((list-limit 2) (offset 2)) + (query + (:limit + (:order-by + (:select 'countries.id 'countries.name + :from 'countries) + 'name) + '$1 '$2) + list-limit offset)) + + ((140 "Algeria") (34 "All")) +#+end_src diff --git a/doc/s-sql-m.html b/doc/s-sql-m.html new file mode 100644 index 0000000..db2511a --- /dev/null +++ b/doc/s-sql-m.html @@ -0,0 +1,331 @@ + + + + + + +S-SQL Examples M + + + + + + + +
    +
    +

    S-SQL Examples M

    +
    + +
    +

    S-SQL Examples Home Page

    +
    + + + +++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ + + + + + + + + + + + + + + + + + + + + + + + + + + + + +
    ABCDEFGHIJKLMNOPRSTUVWSpecial CharactersCalling Postgresql Stored Functions and Procedures
    +
    +
    + +
    +

    Many to Many Calls

    +
    +

    +Many database records are linked in a many to many relationship with other tables or records. Consider the following query: +

    +
    +
    (query "select countries.id, countries.name, events.name as event
    +               from countries,events,countries_events
    +               where country_id=countries.id
    +                      and events.id=event_id
    +                      and events.id=$1"
    +  29)
    +
    +
    + +

    +This can be rephrased in s-sql as: +

    +
    +
    (query (:select 'countries.id 'countries.name
    +                (:as 'events.name 'event)
    +                :from 'countries 'events 'countries_events
    +                :where (:and  (:= 'country_id 'countries.id)
    +                              (:= 'events.id 'event_id)
    +                              (:= 'events.id '$1)))
    +       29)
    +
    +
    +
    +
    +
    + + \ No newline at end of file diff --git a/doc/s-sql-m.org b/doc/s-sql-m.org new file mode 100644 index 0000000..6f993fe --- /dev/null +++ b/doc/s-sql-m.org @@ -0,0 +1,33 @@ +#+TITLE: S-SQL Examples M +#+OPTIONS: num:nil +#+HTML_HEAD: +#+HTML_HEAD: +#+OPTIONS: ^:nil + +* [[file:s-sql-examples.org][S-SQL Examples Home Page]] +| [[file:s-sql-a.org][A]]| [[file:s-sql-b.org][B]]| [[file:s-sql-c.org][C]]| [[file:s-sql-d.org][D]]| [[file:s-sql-e.org][E]]| [[file:s-sql-f.org][F]]| [[file:s-sql-g.org][G]]| [[file:s-sql-h.org][H]]| [[file:s-sql-i.org][I]]| [[file:s-sql-j.org][J]]| [[file:s-sql-k.org][K]]| [[file:s-sql-l.org][L]]| [[file:s-sql-m.org][M]]| [[file:s-sql-n.org][N]]| [[file:s-sql-o.org][O]]| [[file:s-sql-p.org][P]]| [[file:s-sql-r.org][R]]| [[file:s-sql-s.org][S]]| [[file:s-sql-t.org][T]]| [[file:s-sql-u.org][U]]| [[file:s-sql-v.org][V]]| [[file:s-sql-w.org][W]]| [[file:s-sql-special-characters.org][Special Characters]] | [[file:calling-postgresql-stored-functions.org][Calling Postgresql Stored Functions and Procedures]]| + +* Many to Many Calls + :PROPERTIES: + :CUSTOM_ID: many-to-many + :END: +Many database records are linked in a many to many relationship with other tables or records. Consider the following query: +#+begin_src lisp +(query "select countries.id, countries.name, events.name as event + from countries,events,countries_events + where country_id=countries.id + and events.id=event_id + and events.id=$1" + 29) +#+end_src + +This can be rephrased in s-sql as: +#+begin_src lisp +(query (:select 'countries.id 'countries.name + (:as 'events.name 'event) + :from 'countries 'events 'countries_events + :where (:and (:= 'country_id 'countries.id) + (:= 'events.id 'event_id) + (:= 'events.id '$1))) + 29) +#+end_src diff --git a/doc/s-sql-n.html b/doc/s-sql-n.html new file mode 100644 index 0000000..608bcb4 --- /dev/null +++ b/doc/s-sql-n.html @@ -0,0 +1,369 @@ + + + + + + +S-SQL Examples N + + + + + + + +
    +
    +

    S-SQL Examples N

    +
    + +
    +

    S-SQL Examples Home Page

    +
    + + + +++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ + + + + + + + + + + + + + + + + + + + + + + + + + + + + +
    ABCDEFGHIJKLMNOPRSTUVWSpecial CharactersCalling Postgresql Stored Functions and Procedures
    +
    +
    + +
    +

    Null

    +
    +

    +I have a few "groups of countries" in a countries table that should not have a latitude such as the EU. As a result so I would expect to be able to find them by looking for records with null in the latitude field. The second example is similar, looking for any countries with either a null latitude or null longitude. In my particular database, the only "country" matching that is the EU. +

    +
    +
    (query (:select 'id 'name
    +                :from 'countries
    +                :where (:is-null 'latitude)))
    +
    +((6 "EU"))
    +
    +(query (:select 'name :from 'countries
    +        :where (:or (:is-null 'latitude)
    +                    (:is-null 'longitude))))
    +
    +(("EU"))
    +
    +
    + + +

    +The next gives the number of records (without using the sql count operator) from countries where the currency field was both not null and did not consist of just a blank string. +

    +
    +
    (length
    + (query (:select 'id
    +         :from 'countries
    +         :where (:and (:not (:= "" 'countries.currency))
    +                      (:not (:is-null 'countries.currency))))))
    +
    +
    +
    +
    + +
    +

    Not-Null

    +
    +

    +Similarly, you can use :not-null +

    +
    +
    (query (:select 'ta :from 'a :where (:not-null 'ta)))
    +
    +
    +
    +
    + +
    +

    Nullif

    +
    +

    +Suppose you want to perform division, but do not know if the divisor could be zero. The following will handle that and return 0 in that case. +

    +
    +
    (let ((divisor 3))
    +  (query (:select (:coalesce (:/ 12 (:nullif divisor 0 )) 0))
    +         :single))
    +
    +(let ((divisor 0))
    +  (query (:select (:coalesce (:/ 12 (:nullif divisor 0 )) 0))
    +         :single))
    +
    +
    +
    +
    +
    + + \ No newline at end of file diff --git a/doc/s-sql-n.org b/doc/s-sql-n.org new file mode 100644 index 0000000..0c9cdfd --- /dev/null +++ b/doc/s-sql-n.org @@ -0,0 +1,61 @@ +#+TITLE: S-SQL Examples N +#+OPTIONS: num:nil +#+HTML_HEAD: +#+HTML_HEAD: +#+OPTIONS: ^:nil + +* [[file:s-sql-examples.org][S-SQL Examples Home Page]] +| [[file:s-sql-a.org][A]]| [[file:s-sql-b.org][B]]| [[file:s-sql-c.org][C]]| [[file:s-sql-d.org][D]]| [[file:s-sql-e.org][E]]| [[file:s-sql-f.org][F]]| [[file:s-sql-g.org][G]]| [[file:s-sql-h.org][H]]| [[file:s-sql-i.org][I]]| [[file:s-sql-j.org][J]]| [[file:s-sql-k.org][K]]| [[file:s-sql-l.org][L]]| [[file:s-sql-m.org][M]]| [[file:s-sql-n.org][N]]| [[file:s-sql-o.org][O]]| [[file:s-sql-p.org][P]]| [[file:s-sql-r.org][R]]| [[file:s-sql-s.org][S]]| [[file:s-sql-t.org][T]]| [[file:s-sql-u.org][U]]| [[file:s-sql-v.org][V]]| [[file:s-sql-w.org][W]]| [[file:s-sql-special-characters.org][Special Characters]] | [[file:calling-postgresql-stored-functions.org][Calling Postgresql Stored Functions and Procedures]]| + +* Null + :PROPERTIES: + :CUSTOM_ID: null + :END: +I have a few "groups of countries" in a countries table that should not have a latitude such as the EU. As a result so I would expect to be able to find them by looking for records with null in the latitude field. The second example is similar, looking for any countries with either a null latitude or null longitude. In my particular database, the only "country" matching that is the EU. +#+begin_src lisp + (query (:select 'id 'name + :from 'countries + :where (:is-null 'latitude))) + + ((6 "EU")) + + (query (:select 'name :from 'countries + :where (:or (:is-null 'latitude) + (:is-null 'longitude)))) + + (("EU")) +#+end_src + + +The next gives the number of records (without using the sql count operator) from countries where the currency field was both not null and did not consist of just a blank string. +#+begin_src lisp + (length + (query (:select 'id + :from 'countries + :where (:and (:not (:= "" 'countries.currency)) + (:not (:is-null 'countries.currency)))))) +#+end_src + +* Not-Null + :PROPERTIES: + :CUSTOM_ID: not-null + :END: +Similarly, you can use :not-null +#+begin_src lisp +(query (:select 'ta :from 'a :where (:not-null 'ta))) +#+end_src + +* Nullif + :PROPERTIES: + :CUSTOM_ID: nullif + :END: +Suppose you want to perform division, but do not know if the divisor could be zero. The following will handle that and return 0 in that case. +#+begin_src lisp +(let ((divisor 3)) + (query (:select (:coalesce (:/ 12 (:nullif divisor 0 )) 0)) + :single)) + +(let ((divisor 0)) + (query (:select (:coalesce (:/ 12 (:nullif divisor 0 )) 0)) + :single)) +#+end_src diff --git a/doc/s-sql-o.html b/doc/s-sql-o.html new file mode 100644 index 0000000..f66dbca --- /dev/null +++ b/doc/s-sql-o.html @@ -0,0 +1,627 @@ + + + + + + +S-SQL Examples O + + + + + + + +
    +
    +

    S-SQL Examples O

    +
    + +
    +

    S-SQL Examples Home Page

    +
    + + + +++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ + + + + + + + + + + + + + + + + + + + + + + + + + + + + +
    ABCDEFGHIJKLMNOPRSTUVWSpecial CharactersCalling Postgresql Stored Functions and Procedures
    +
    +
    + +
    +

    On

    +
    +

    +On is used in the join clauses. See the example below which returns a list of lists showing various types of items inside a database. +

    +
    +
    (defun list-schema-table-type-owner (relkind-type)
    +  "Returns a list of lists showing the schema, the name, the type and the ownerwhere relkind-type is a list of strings where the strings are: c,r,v,i,S,c,t or f"
    +  (query (:order-by (:select (:as 'n.nspname 'Schema)
    +                             (:as 'c.relname 'Name)
    +                             (:as (:case ((:= 'c.relkind "r") "Table")
    +                                    ((:= 'c.relkind "v") "view")
    +                                    ((:= 'c.relkind "i") "index")
    +                                    ((:= 'c.relkind "S") "sequence")
    +                                    ((:= 'c.relkind "c") "composite")
    +                                    ((:= 'c.relkind "t") "TOAST")
    +                                    ((:= 'c.relkind "f") "foreign"))
    +                                  'Type)
    +                             (:as 'u.usename 'Owner)
    +                             (:as (:/ (:pg_total_relation_size 'c.oid) 1000) 'Size)
    +                             (:as 'c.reltuples 'Records)
    +                             (:as 'c.relhasindex 'Indexed)
    +                             (:as 'c.relchecks 'Constraints)
    +                             (:as 'c.relhastriggers 'Triggers)
    +                             (:as (:pg_size_pretty (:pg_total_relation_size 'c.oid)) 'Size)
    +                             :from (:as 'pg-catalog.pg-class 'c)
    +                             :left-join (:as 'pg-catalog.pg-user 'u)
    +                             :on (:= 'u.usesysid  'c.relowner)
    +                             :left-join (:as 'pg-catalog.pg-namespace  'n)
    +                             :on (:= 'n.oid  'c.relnamespace)
    +                             :where (:and (:in 'c.relkind (:set relkind-type ""))
    +                                          (:not-in 'n.nspname (:set "pg_catalog" "pg-toast"))
    +                                          (:pg-catalog.pg-table-is-visible 'c.oid)))
    +                    1 2)))
    +
    +
    +
    +
    + +
    +

    On Conflict

    +
    +

    +Some people use the term "upsert" for trying to insert a new row, but if that record already exists, then either update the row with new values or do nothing (as opposed to throwing an error). +

    + +

    +Beginning in postgresql versions 9.5 and above, it is possible to use what postgresql calls on-conflict. There are two versions - "on conflict do nothing" or "on conflict update". See below for sample call in postmodern for on-conflict-update. +

    + +
    +
    (query (:insert-into 'test-table :set 'column-A '$1 'column-B '$2
    +                     :on-conflict-update 'column-A
    +                     :update-set 'column-B '$2
    +                     :where (:= 'test-table.column-A '$1)) "c" 37)
    +
    +
    +
    +
    +
    + +
    +

    Or

    +
    +
    +
    (query (:select 'countries.name :from 'countries 'regions
    +                :where (:and (:or (:= 'regions.name "North America")
    +                                  (:= 'regions.name "Central America"))
    +                             (:= 'regions.id 'countries.region-id))))
    +
    +(("Belize") ("Bermuda") ("Canada") ("Costa Rica") ("El Salvador") ("Greenland")  ("Guatemala") ("Mexico") ("Panama") ("US") ("Nicaragua"))
    +
    +
    +
    +
    +
    + +
    +

    Order-by

    +
    +

    +Order-by does what it says on the label. It is important to note that there are two uses of order-by. First is a wrapper around a select statement, effectively sorting the data returned by the select statement.: +

    +
    +
    (query (:order-by
    +        (:select 'id 'name
    +                 :from 'countries
    +                 :where (:>= 'name "W"))
    +        'name))
    +
    +((115 "Wallis") (141 "Zambia") (142 "Zimbabwe"))
    +
    +
    + +

    +If you want to change the default from ascending to descending, then the relevant column name is enclosed in a :desc term like so: +

    +
    +
    (query (:order-by
    +        (:select 'id 'name
    +                 :from 'countries
    +                 :where (:>= 'name "W"))
    +        (:desc 'name)))
    +
    +((142 "Zimbabwe") (141 "Zambia") (115 "Wallis") )
    +
    +
    +
    + +
    +

    Order By with Limit and offset

    +
    +

    +Note that :order-by has one or more parameters [Just one in this example] and :limit has 2 possible parameters, the limit and the offset. Note that the :order-by and :limit forms are wrapped around the :select form. The only difference between the two queries is the offset parameter. +

    +
    +
    (let ((list-limit 2) (offset 0))
    +  (query
    +   (:limit
    +    (:order-by
    +     (:select 'countries.id 'countries.name
    +              :from 'countries)
    +     'name)
    +    '$1 '$2)
    +   list-limit offset))
    +
    +((82 "Afghanistan") (130 "Albania"))
    +
    +(let ((list-limit 2)
    +      (offset 2))
    +  (query
    +   (:limit
    +    (:order-by
    +     (:select 'countries.id 'countries.name
    +              :from 'countries)
    +     'name)
    +    '$1 '$2)
    +   list-limit offset))
    +
    +((140 "Algeria") (34 "All"))
    +
    +
    +
    +
    +
    + +
    +

    Order-by within an aggregation operator

    +
    +

    +The second use of order-by is as a keyword parameter to an aggregation operator. +

    + +

    +Since it is part of the aggregation operator rather than sorting the result of the aggregation operator, it is not a wrap around form as seen above. +

    +
    +
    +
    +
    +

    Over

    +
    +

    +Over is a part of Postgresql window functions. "The OVER clause determines exactly how the rows of the query are split up for processing by the window function. The PARTITION BY clause within OVER divides the rows into groups, or partitions, that share the same values of the PARTITION BY expression(s). For each row, the window function is computed across the rows that fall into the same partition as the current row. +

    + +

    +You can also control the order in which rows are processed by window functions using ORDER BY within OVER. (The window ORDER BY does not even have to match the order in which the rows are output.)" See also the examples for partition-by +

    + +

    +Here is an example: +

    +
    +
    (query (:select 'salary (:over (:sum 'salary))
    +              :from 'empsalary))
    +
    +
    + +

    +Consider briefly at what "over" generates" +

    +
    +
      (sql (:over 'x 'y))
    +
    +"(x OVER y)"
    +
    +(sql (:over 'x))
    +
    +"(x OVER ())"
    +
    +(sql (:over 'x 'y 'z))
    +
    +"(x OVER y, z)"
    +
    +
    + +

    +So, if you wanted an sql statement such as: +

    +
    +
     (query "select x, array_agg(x) over (order by x) from generate_series(1, 3) as t(x);")
    +
    +((1 #(1)) (2 #(1 2)) (3 #(1 2 3)))
    +
    +
    + +

    +The postmodern version would be: +

    +
    +
     (query (:select 'x
    +                (:over (:array-agg 'x)
    +                       (:order-by 'x))
    +                :from (:as (:generate-series 1 3)
    +                           (:t 'x))))
    +
    +((1 #(1)) (2 #(1 2)) (3 #(1 2 3)))
    +
    +
    +
    +
    +

    Over Range Between

    +
    +
    +
    (query (:limit
    +        (:select (:as 'country 'country-name)
    +                 (:as 'population 'country-population)
    +                 (:as (:over (:sum 'population)
    +                             (:range-between :order-by 'country :unbounded-preceding
    +                              :unbounded-following))
    +                      'global-population)
    +         :from 'population
    +         :where (:and (:not-null 'iso2)
    +                      (:= 'year 1976)))
    +        5))
    +
    +
    +
    +
    +
    +

    Over Row Between

    +
    +
    +
    +

    Preceding

    +
    +
    +
    (query (:limit
    +           (:select (:as 'country 'country-name)
    +                    (:as 'population 'country-population)
    +                    (:as (:over (:sum 'population)
    +                                (:rows-between :order-by 'country :preceding 2
    +                                               :following 2))
    +                         'global-population)
    +                    :from 'population
    +                    :where (:and (:not-null 'iso2)
    +                                 (:= 'year 1976)))
    +           5))
    +
    +
    +
    +
    +
    +

    Current-Row

    +
    +
    +
    (query (:limit
    +           (:select (:as 'country 'country-name)
    +                    (:as 'population 'country-population)
    +                    (:as (:over (:sum 'population)
    +                                (:rows-between :order-by 'country :current-row
    +                                 :following 2))
    +                         'global-population)
    +                    :from 'population
    +                    :where (:and (:not-null 'iso2)
    +                                 (:= 'year 1976)))
    +           5))
    +
    +
    +
    +
    +
    +

    Unbounded

    +
    +
    +
    (query (:limit
    +           (:select (:as 'population.country 'country-name)
    +                    (:as 'population 'country-population)
    +                    'region-name
    +                    (:as (:over (:sum 'population)
    +                                (:partition-by 'region-name :order-by 'population.country
    +                                 :range-between :unbounded-preceding :current-row))
    +                         'regional-population)
    +                    :from 'population
    +                    :inner-join 'regions
    +                    :on (:= 'population.iso3 'regions.iso3)
    +                    :where (:and (:not-null 'population.iso2)
    +                                 (:= 'year 1976)))
    +           5))
    +
    +
    +
    +
    +
    +
    +
    + + \ No newline at end of file diff --git a/doc/s-sql-o.org b/doc/s-sql-o.org new file mode 100644 index 0000000..f0a4d71 --- /dev/null +++ b/doc/s-sql-o.org @@ -0,0 +1,257 @@ +#+TITLE: S-SQL Examples O +#+OPTIONS: num:nil +#+HTML_HEAD: +#+HTML_HEAD: +#+OPTIONS: ^:nil + +* [[file:s-sql-examples.org][S-SQL Examples Home Page]] +| [[file:s-sql-a.org][A]]| [[file:s-sql-b.org][B]]| [[file:s-sql-c.org][C]]| [[file:s-sql-d.org][D]]| [[file:s-sql-e.org][E]]| [[file:s-sql-f.org][F]]| [[file:s-sql-g.org][G]]| [[file:s-sql-h.org][H]]| [[file:s-sql-i.org][I]]| [[file:s-sql-j.org][J]]| [[file:s-sql-k.org][K]]| [[file:s-sql-l.org][L]]| [[file:s-sql-m.org][M]]| [[file:s-sql-n.org][N]]| [[file:s-sql-o.org][O]]| [[file:s-sql-p.org][P]]| [[file:s-sql-r.org][R]]| [[file:s-sql-s.org][S]]| [[file:s-sql-t.org][T]]| [[file:s-sql-u.org][U]]| [[file:s-sql-v.org][V]]| [[file:s-sql-w.org][W]]| [[file:s-sql-special-characters.org][Special Characters]] | [[file:calling-postgresql-stored-functions.org][Calling Postgresql Stored Functions and Procedures]]| + +* On + :PROPERTIES: + :CUSTOM_ID: on + :END: +On is used in the join clauses. See the example below which returns a list of lists showing various types of items inside a database. +#+begin_src lisp + (defun list-schema-table-type-owner (relkind-type) + "Returns a list of lists showing the schema, the name, the type and the ownerwhere relkind-type is a list of strings where the strings are: c,r,v,i,S,c,t or f" + (query (:order-by (:select (:as 'n.nspname 'Schema) + (:as 'c.relname 'Name) + (:as (:case ((:= 'c.relkind "r") "Table") + ((:= 'c.relkind "v") "view") + ((:= 'c.relkind "i") "index") + ((:= 'c.relkind "S") "sequence") + ((:= 'c.relkind "c") "composite") + ((:= 'c.relkind "t") "TOAST") + ((:= 'c.relkind "f") "foreign")) + 'Type) + (:as 'u.usename 'Owner) + (:as (:/ (:pg_total_relation_size 'c.oid) 1000) 'Size) + (:as 'c.reltuples 'Records) + (:as 'c.relhasindex 'Indexed) + (:as 'c.relchecks 'Constraints) + (:as 'c.relhastriggers 'Triggers) + (:as (:pg_size_pretty (:pg_total_relation_size 'c.oid)) 'Size) + :from (:as 'pg-catalog.pg-class 'c) + :left-join (:as 'pg-catalog.pg-user 'u) + :on (:= 'u.usesysid 'c.relowner) + :left-join (:as 'pg-catalog.pg-namespace 'n) + :on (:= 'n.oid 'c.relnamespace) + :where (:and (:in 'c.relkind (:set relkind-type "")) + (:not-in 'n.nspname (:set "pg_catalog" "pg-toast")) + (:pg-catalog.pg-table-is-visible 'c.oid))) + 1 2))) +#+end_src + +* On Conflict + :PROPERTIES: + :CUSTOM_ID: on-conflict + :END: +Some people use the term "upsert" for trying to insert a new row, but if that record already exists, then either update the row with new values or do nothing (as opposed to throwing an error). + +Beginning in postgresql versions 9.5 and above, it is possible to use what postgresql calls on-conflict. There are two versions - "on conflict do nothing" or "on conflict update". See below for sample call in postmodern for on-conflict-update. + +#+begin_src lisp +(query (:insert-into 'test-table :set 'column-A '$1 'column-B '$2 + :on-conflict-update 'column-A + :update-set 'column-B '$2 + :where (:= 'test-table.column-A '$1)) "c" 37) + +#+end_src + +* Or + :PROPERTIES: + :CUSTOM_ID: or + :END: +#+begin_src lisp +(query (:select 'countries.name :from 'countries 'regions + :where (:and (:or (:= 'regions.name "North America") + (:= 'regions.name "Central America")) + (:= 'regions.id 'countries.region-id)))) + +(("Belize") ("Bermuda") ("Canada") ("Costa Rica") ("El Salvador") ("Greenland") ("Guatemala") ("Mexico") ("Panama") ("US") ("Nicaragua")) + +#+end_src + +* Order-by + :PROPERTIES: + :CUSTOM_ID: order-by + :END: +Order-by does what it says on the label. It is important to note that there are two uses of order-by. First is a wrapper around a select statement, effectively sorting the data returned by the select statement.: +#+begin_src lisp +(query (:order-by + (:select 'id 'name + :from 'countries + :where (:>= 'name "W")) + 'name)) + +((115 "Wallis") (141 "Zambia") (142 "Zimbabwe")) +#+end_src + +If you want to change the default from ascending to descending, then the relevant column name is enclosed in a :desc term like so: +#+begin_src lisp +(query (:order-by + (:select 'id 'name + :from 'countries + :where (:>= 'name "W")) + (:desc 'name))) + +((142 "Zimbabwe") (141 "Zambia") (115 "Wallis") ) +#+end_src + +** Order By with Limit and offset + :PROPERTIES: + :CUSTOM_ID: order-by-with-limit + :END: +Note that :order-by has one or more parameters [Just one in this example] and :limit has 2 possible parameters, the limit and the offset. Note that the :order-by and :limit forms are wrapped around the :select form. The only difference between the two queries is the offset parameter. +#+begin_src lisp + (let ((list-limit 2) (offset 0)) + (query + (:limit + (:order-by + (:select 'countries.id 'countries.name + :from 'countries) + 'name) + '$1 '$2) + list-limit offset)) + + ((82 "Afghanistan") (130 "Albania")) + + (let ((list-limit 2) + (offset 2)) + (query + (:limit + (:order-by + (:select 'countries.id 'countries.name + :from 'countries) + 'name) + '$1 '$2) + list-limit offset)) + + ((140 "Algeria") (34 "All")) + +#+end_src + +** Order-by within an aggregation operator + +The second use of order-by is as a keyword parameter to an aggregation operator. + +Since it is part of the aggregation operator rather than sorting the result of the aggregation operator, it is not a wrap around form as seen above. +* Over + :PROPERTIES: + :CUSTOM_ID: over + :END: +Over is a part of [[https://www.postgresql.org/docs/current/tutorial-window.html][Postgresql window functions]]. "The OVER clause determines exactly how the rows of the query are split up for processing by the window function. The PARTITION BY clause within OVER divides the rows into groups, or partitions, that share the same values of the PARTITION BY expression(s). For each row, the window function is computed across the rows that fall into the same partition as the current row. + +You can also control the order in which rows are processed by window functions using ORDER BY within OVER. (The window ORDER BY does not even have to match the order in which the rows are output.)" See also the examples for partition-by + +Here is an example: +#+begin_src lisp + (query (:select 'salary (:over (:sum 'salary)) + :from 'empsalary)) +#+end_src + +Consider briefly at what "over" generates" +#+begin_src lisp + (sql (:over 'x 'y)) + +"(x OVER y)" + +(sql (:over 'x)) + +"(x OVER ())" + +(sql (:over 'x 'y 'z)) + +"(x OVER y, z)" +#+end_src + +So, if you wanted an sql statement such as: +#+begin_src lisp + (query "select x, array_agg(x) over (order by x) from generate_series(1, 3) as t(x);") + +((1 #(1)) (2 #(1 2)) (3 #(1 2 3))) +#+end_src + +The postmodern version would be: +#+begin_src lisp + (query (:select 'x + (:over (:array-agg 'x) + (:order-by 'x)) + :from (:as (:generate-series 1 3) + (:t 'x)))) + +((1 #(1)) (2 #(1 2)) (3 #(1 2 3))) +#+end_src +** Over Range Between + :PROPERTIES: + :CUSTOM_ID: over-range-between + :END: +#+begin_src lisp + (query (:limit + (:select (:as 'country 'country-name) + (:as 'population 'country-population) + (:as (:over (:sum 'population) + (:range-between :order-by 'country :unbounded-preceding + :unbounded-following)) + 'global-population) + :from 'population + :where (:and (:not-null 'iso2) + (:= 'year 1976))) + 5)) +#+end_src +** Over Row Between +*** Preceding + :PROPERTIES: + :CUSTOM_ID: preceding + :END: +#+begin_src lisp + (query (:limit + (:select (:as 'country 'country-name) + (:as 'population 'country-population) + (:as (:over (:sum 'population) + (:rows-between :order-by 'country :preceding 2 + :following 2)) + 'global-population) + :from 'population + :where (:and (:not-null 'iso2) + (:= 'year 1976))) + 5)) +#+end_src +*** Current-Row + :PROPERTIES: + :CUSTOM_ID: current-row + :END: +#+begin_src lisp + (query (:limit + (:select (:as 'country 'country-name) + (:as 'population 'country-population) + (:as (:over (:sum 'population) + (:rows-between :order-by 'country :current-row + :following 2)) + 'global-population) + :from 'population + :where (:and (:not-null 'iso2) + (:= 'year 1976))) + 5)) +#+end_src +*** Unbounded + :PROPERTIES: + :CUSTOM_ID: unbounded + :END: +#+begin_src lisp + (query (:limit + (:select (:as 'population.country 'country-name) + (:as 'population 'country-population) + 'region-name + (:as (:over (:sum 'population) + (:partition-by 'region-name :order-by 'population.country + :range-between :unbounded-preceding :current-row)) + 'regional-population) + :from 'population + :inner-join 'regions + :on (:= 'population.iso3 'regions.iso3) + :where (:and (:not-null 'population.iso2) + (:= 'year 1976))) + 5)) +#+end_src diff --git a/doc/s-sql-p.html b/doc/s-sql-p.html new file mode 100644 index 0000000..bcce46f --- /dev/null +++ b/doc/s-sql-p.html @@ -0,0 +1,448 @@ + + + + + + +S-SQL Examples P + + + + + + + +
    +
    +

    S-SQL Examples P

    +
    + +
    +

    S-SQL Examples Home Page

    +
    + + + +++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ + + + + + + + + + + + + + + + + + + + + + + + + + + + + +
    ABCDEFGHIJKLMNOPRSTUVWSpecial CharactersCalling Postgresql Stored Functions and Procedures
    +
    +
    + +
    +

    Parameterized Statements

    +
    +

    +Parameterized statements help protect against sql injection and some of the examples above have used parameterized statement forms. You can't parameterize table names, column names or sql keywords. So if you are getting those from the user, you definitely need to sanitize the input. Parameterized statements also don't protect against other things like cross-script attacks, so you still need to sanitize input. +

    + +

    +The following is a simple parameterized query and a prepared statement using parameters. First, the pure sql version +

    +
    +
    (query "select name from countries where name=$1"
    +       "France" :single)
    +
    +
    + +

    +Now the s-sql version: +

    +
    +
    (query (:select 'id :from 'countries :where (:= 'name '$1))
    +       "France" :single)
    +
    +
    + +

    +Now the simple prepared statement version in standard sql and s-sql: +

    +
    +
    (defprepared test21 "select name from countries where id=$1")
    +
    +(test21 5)
    +
    +("Denmark")
    +
    +
    +

    +Now the s-sql version +

    +
    +
    (defprepared test22
    +  (:select 'name
    +           :from 'countries
    +           :where (:= 'id '$1)))
    +
    +(test22 5)
    +
    +("Denmark")
    +
    +
    +

    +Now let's change the simple version to one where you want to give it a list. We are going to use the :column parameter to indicate we just want a single list of all the country names found with the select statement. +

    +
    +
    (defprepared test23 "select name from countries where id=any($1)"
    +  :column)
    +
    +(test23 '(21 6 5))
    +
    +("EU" "Denmark" "US")
    +
    +
    +

    +You also get the same result if you pass a vector instead of a list. +

    +
    +
    (test23
    + (vector 21 6 5))
    +
    +("EU" "Denmark" "US")
    +
    +
    + +

    +You cannot use a list or vector with the sql keyword "in". E.g. +

    +
    +
    (query "select name from countries where id in $1" '(21 20))
    +
    +Evaluation aborted on #<CL-POSTGRES-ERROR:SYNTAX-ERROR-OR-ACCESS-VIOLATION {100C262F31}>.
    +
    +
    +
    + +

    +You can, however, use a list or a vector with the keyword any. E.g. +

    +
    +
    (query "select name from countries where id = any($1)"
    +       (coerce '(21 20) 'vector)
    +       :column)
    +
    +("UK" "US")
    +
    +(query "select name from countries where id = any($1)"
    +     '(21 20) )
    +
    +    ("UK" "US")
    +
    +
    + +

    +Now the s-sql version. Note the change for any to any* +

    +
    +
      (query (:select 'name
    +                  :from 'countries
    +                  :where (:= 'id (:any* '$1)))
    +         '(21 20) :column)
    +
    +  ("UK" "US")
    +
    +  (query (:select 'name
    +                :from 'countries
    +                :where (:= 'id (:any* '$1)))
    +       (vector 21 20) :column)
    +
    +("UK" "US")
    +
    +
    +
    +
    + +
    +

    Partition-by

    +
    +

    +Partition-by is not table partitioning. Rather it is a clause that allows you to set the range of records that will be used for each group within an over clause. Consider it a windowing function. Partition-by is available in Postmodern as of the Oct 29, 2013 git version. +

    + +

    +Important: Note use of :order-by without being the function call at the beginning of a form. +

    +
    +
    (query (:select 'depname 'empno 'salary
    +                (:over (:avg 'salary)
    +                       (:partition-by 'depname))
    +                :from 'empsalary))
    +
    +(query (:select 'depname 'empno 'salary
    +                (:over (:rank)
    +                       (:partition-by 'depname :order-by (:desc 'salary)))
    +                :from 'empsalary))
    +
    +
    +
    +
    +
    + + \ No newline at end of file diff --git a/doc/s-sql-p.org b/doc/s-sql-p.org new file mode 100644 index 0000000..20ff01e --- /dev/null +++ b/doc/s-sql-p.org @@ -0,0 +1,120 @@ +#+TITLE: S-SQL Examples P +#+OPTIONS: num:nil +#+HTML_HEAD: +#+HTML_HEAD: +#+OPTIONS: ^:nil + +* [[file:s-sql-examples.org][S-SQL Examples Home Page]] +| [[file:s-sql-a.org][A]]| [[file:s-sql-b.org][B]]| [[file:s-sql-c.org][C]]| [[file:s-sql-d.org][D]]| [[file:s-sql-e.org][E]]| [[file:s-sql-f.org][F]]| [[file:s-sql-g.org][G]]| [[file:s-sql-h.org][H]]| [[file:s-sql-i.org][I]]| [[file:s-sql-j.org][J]]| [[file:s-sql-k.org][K]]| [[file:s-sql-l.org][L]]| [[file:s-sql-m.org][M]]| [[file:s-sql-n.org][N]]| [[file:s-sql-o.org][O]]| [[file:s-sql-p.org][P]]| [[file:s-sql-r.org][R]]| [[file:s-sql-s.org][S]]| [[file:s-sql-t.org][T]]| [[file:s-sql-u.org][U]]| [[file:s-sql-v.org][V]]| [[file:s-sql-w.org][W]]| [[file:s-sql-special-characters.org][Special Characters]] | [[file:calling-postgresql-stored-functions.org][Calling Postgresql Stored Functions and Procedures]]| + +* Parameterized Statements + :PROPERTIES: + :CUSTOM_ID: parameterized + :END: +Parameterized statements help protect against sql injection and some of the examples above have used parameterized statement forms. You can't parameterize table names, column names or sql keywords. So if you are getting those from the user, you definitely need to sanitize the input. Parameterized statements also don't protect against other things like cross-script attacks, so you still need to sanitize input. + +The following is a simple parameterized query and a prepared statement using parameters. First, the pure sql version +#+begin_src lisp + (query "select name from countries where name=$1" + "France" :single) +#+end_src + +Now the s-sql version: +#+begin_src lisp + (query (:select 'id :from 'countries :where (:= 'name '$1)) + "France" :single) +#+end_src + +Now the simple prepared statement version in standard sql and s-sql: +#+begin_src lisp +(defprepared test21 "select name from countries where id=$1") + +(test21 5) + +("Denmark") +#+end_src +Now the s-sql version +#+begin_src lisp +(defprepared test22 + (:select 'name + :from 'countries + :where (:= 'id '$1))) + +(test22 5) + +("Denmark") +#+end_src +Now let's change the simple version to one where you want to give it a list. We are going to use the :column parameter to indicate we just want a single list of all the country names found with the select statement. +#+begin_src lisp + (defprepared test23 "select name from countries where id=any($1)" + :column) + + (test23 '(21 6 5)) + + ("EU" "Denmark" "US") +#+end_src +You also get the same result if you pass a vector instead of a list. +#+begin_src lisp + (test23 + (vector 21 6 5)) + + ("EU" "Denmark" "US") +#+end_src + +You cannot use a list or vector with the sql keyword "in". E.g. +#+begin_src lisp +(query "select name from countries where id in $1" '(21 20)) + +Evaluation aborted on #. + +#+end_src + +You can, however, use a list or a vector with the keyword any. E.g. +#+begin_src lisp + (query "select name from countries where id = any($1)" + (coerce '(21 20) 'vector) + :column) + + ("UK" "US") + + (query "select name from countries where id = any($1)" + '(21 20) ) + + ("UK" "US") +#+end_src + +Now the s-sql version. Note the change for any to any* +#+begin_src lisp + (query (:select 'name + :from 'countries + :where (:= 'id (:any* '$1))) + '(21 20) :column) + + ("UK" "US") + + (query (:select 'name + :from 'countries + :where (:= 'id (:any* '$1))) + (vector 21 20) :column) + +("UK" "US") +#+end_src + +* Partition-by + :PROPERTIES: + :CUSTOM_ID: partition-by + :END: +Partition-by is not table partitioning. Rather it is a clause that allows you to set the range of records that will be used for each group within an over clause. Consider it a windowing function. Partition-by is available in Postmodern as of the Oct 29, 2013 git version. + +Important: Note use of :order-by without being the function call at the beginning of a form. +#+begin_src lisp +(query (:select 'depname 'empno 'salary + (:over (:avg 'salary) + (:partition-by 'depname)) + :from 'empsalary)) + +(query (:select 'depname 'empno 'salary + (:over (:rank) + (:partition-by 'depname :order-by (:desc 'salary))) + :from 'empsalary)) +#+end_src diff --git a/doc/s-sql-postgresql-functions.html b/doc/s-sql-postgresql-functions.html new file mode 100644 index 0000000..25eb348 --- /dev/null +++ b/doc/s-sql-postgresql-functions.html @@ -0,0 +1,458 @@ + + + + + + +S-SQL and Postgresql Functions + + + + + + + +
    +
    +

    S-SQL and Postgresql Functions

    +
    + +
    +

    S-SQL Examples Home Page

    +
    + + + +++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ + + + + + + + + + + + + + + + + + + + + + + + + + + + + +
    ABCDEFGHIJKLMNOPRSTUVWSpecial CharactersCalling Postgresql Stored Functions and Procedures
    +
    +
    + +
    +

    Postgresql Functions

    +
    +

    +Postgresql functions are typically inserted into s-sql in their own form prefaced with : and their parameters are generally single quoted. Here are a few simple examples. +

    +
    + +
    +

    :avg

    +
    +
    +
    (froundn (query (:select (:avg 'latitude) :from 'countries) :single) 4)
    +
    +18.4209
    +
    +
    +
    +
    + +
    +

    :generate-series

    +
    +

    +Generate-series returns a list of of lists of numbers with a starting point of x, and ending point of y and an interval of z (defaulting to 1). Thus: +

    +
    +
    (query (:select '* :from (:generate-series 1 10)))
    +
    +((1) (2) (3) (4) (5) (6) (7) (8) (9) (10))
    +
    +(query (:select '* :from (:generate-series 1 30 5)))
    +
    +((1) (6) (11) (16) (21) (26))
    +
    +(query (:select '* :from (:generate-series 3 30 5)))
    +
    +((3) (8) (13) (18) (23) (28))
    +
    +
    +
    +
    +
    + +
    +

    :max

    +
    +
    +
    (query (:select (:max 'latitude) :from 'countries)
    +       :single)
    +
    +72
    +
    +
    +
    +
    + +
    +

    :min

    +
    +
    +
    (query (:select (:min 'latitude) :from 'countries)
    +       :single)
    +
    +-1029/20
    +
    +
    +
    +
    +
    + +
    +

    :random

    +
    +
    +
    (query (:limit
    +        (:order-by
    +         (:select 'id 'name :from 'countries)
    +         (:random))
    + 5))
    +
    +((54 "Israel") (62 "South Africa") (195 "Aruba") (79 "Costa Rica") (31 "OECD"))
    +
    +
    +
    +
    +
    + +
    +

    :string_agg

    +
    +

    +String_agg returns a string containging the values returned, separated by a delimiter. In the following example, we are searching for the name of all the regions in the regions table and we want it all returned as a single string with a delimiting comma. +

    +
    +
    (query (:select (:string_agg 'name ",")
    +        :from 'regions))
    +
    + (("Central America,Middle East,North America,South America,Central Asia,Pacific,Caribbean,Eastern Europe,Western Europe,EMEA,APAC,LATAM,Emerging,US,Canada,Africa,All,Asia,Eastern Africa,Middle Africa,Northern Africa,Southern Africa,Western Africa,Oceania,Northern Europe,Southern Europe,Eastern Asia,South Central Asia,South East Asia"))
    +
    +
    +
    +
    +
    + +
    +

    :version

    +
    +
    +
    (query (:select (:version)))
    +
    +(("PostgreSQL 9.2 on x86_64-pc-linux-gnu, compiled by GCC x86_64"))
    +
    +
    +
    +
    +
    (defun table-size (table-name)
    +  "Return the size of a postgresql table in k or m. Table-name can be either astring or quoted."
    +  (when (symbolp table-name)
    +    (setf table-name  (string-downcase (write-to-string table-name))))
    +  (query (:select (:pg_size_pretty (:pg_total_relation_size '$1)))
    +         :single
    +         table-name))
    +
    +(table-size 'countries)
    +
    +"88 kB"
    +
    +
    +
    +
    +
    + +
    +

    Combining Postgresql Functions

    +
    +
    +
    (defun current-database-size-pretty ()
    +  "Returns the current database size as a string in MB"
    +  (query (:select (:pg_size_pretty
    +                   (:pg_database_size (:current_database))))
    +         :single))
    +
    +
    +
    +
    +
    +
    + + \ No newline at end of file diff --git a/doc/s-sql-postgresql-functions.org b/doc/s-sql-postgresql-functions.org new file mode 100644 index 0000000..2fbf631 --- /dev/null +++ b/doc/s-sql-postgresql-functions.org @@ -0,0 +1,132 @@ +#+TITLE: S-SQL and Postgresql Functions +#+OPTIONS: num:nil +#+HTML_HEAD: +#+HTML_HEAD: +#+OPTIONS: ^:nil + +* [[file:s-sql-examples.org][S-SQL Examples Home Page]] +| [[file:s-sql-a.org][A]]| [[file:s-sql-b.org][B]]| [[file:s-sql-c.org][C]]| [[file:s-sql-d.org][D]]| [[file:s-sql-e.org][E]]| [[file:s-sql-f.org][F]]| [[file:s-sql-g.org][G]]| [[file:s-sql-h.org][H]]| [[file:s-sql-i.org][I]]| [[file:s-sql-j.org][J]]| [[file:s-sql-k.org][K]]| [[file:s-sql-l.org][L]]| [[file:s-sql-m.org][M]]| [[file:s-sql-n.org][N]]| [[file:s-sql-o.org][O]]| [[file:s-sql-p.org][P]]| [[file:s-sql-r.org][R]]| [[file:s-sql-s.org][S]]| [[file:s-sql-t.org][T]]| [[file:s-sql-u.org][U]]| [[file:s-sql-v.org][V]]| [[file:s-sql-w.org][W]]| [[file:s-sql-special-characters.org][Special Characters]] | [[file:calling-postgresql-stored-functions.org][Calling Postgresql Stored Functions and Procedures]]| + +* Postgresql Functions +:PROPERTIES: +:CUSTOM_ID: postgresql-functions +:END: +Postgresql functions are typically inserted into s-sql in their own form prefaced with : and their parameters are generally single quoted. Here are a few simple examples. + +** :avg +:PROPERTIES: +:CUSTOM_ID: avg +:END: +#+begin_src lisp + (froundn (query (:select (:avg 'latitude) :from 'countries) :single) 4) + + 18.4209 +#+end_src + +** :generate-series +:PROPERTIES: +:CUSTOM_ID: generate-series +:END: +Generate-series returns a list of of lists of numbers with a starting point of x, and ending point of y and an interval of z (defaulting to 1). Thus: +#+begin_src lisp +(query (:select '* :from (:generate-series 1 10))) + +((1) (2) (3) (4) (5) (6) (7) (8) (9) (10)) + +(query (:select '* :from (:generate-series 1 30 5))) + +((1) (6) (11) (16) (21) (26)) + +(query (:select '* :from (:generate-series 3 30 5))) + +((3) (8) (13) (18) (23) (28)) + +#+end_src + +** :max +:PROPERTIES: +:CUSTOM_ID: max +:END: +#+begin_src lisp + (query (:select (:max 'latitude) :from 'countries) + :single) + + 72 +#+end_src + +** :min +:PROPERTIES: +:CUSTOM_ID: min +:END: +#+begin_src lisp + (query (:select (:min 'latitude) :from 'countries) + :single) + + -1029/20 + +#+end_src + +** :random +:PROPERTIES: +:CUSTOM_ID: random +:END: +#+begin_src lisp + (query (:limit + (:order-by + (:select 'id 'name :from 'countries) + (:random)) + 5)) + + ((54 "Israel") (62 "South Africa") (195 "Aruba") (79 "Costa Rica") (31 "OECD")) + +#+end_src + +** :string_agg +:PROPERTIES: +:CUSTOM_ID: string-agg +:END: +String_agg returns a string containging the values returned, separated by a delimiter. In the following example, we are searching for the name of all the regions in the regions table and we want it all returned as a single string with a delimiting comma. +#+begin_src lisp + (query (:select (:string_agg 'name ",") + :from 'regions)) + + (("Central America,Middle East,North America,South America,Central Asia,Pacific,Caribbean,Eastern Europe,Western Europe,EMEA,APAC,LATAM,Emerging,US,Canada,Africa,All,Asia,Eastern Africa,Middle Africa,Northern Africa,Southern Africa,Western Africa,Oceania,Northern Europe,Southern Europe,Eastern Asia,South Central Asia,South East Asia")) + +#+end_src + +** :version +:PROPERTIES: +:CUSTOM_ID: version +:END: +#+begin_src lisp + (query (:select (:version))) + + (("PostgreSQL 9.2 on x86_64-pc-linux-gnu, compiled by GCC x86_64")) + +#+end_src +#+begin_src lisp + (defun table-size (table-name) + "Return the size of a postgresql table in k or m. Table-name can be either astring or quoted." + (when (symbolp table-name) + (setf table-name (string-downcase (write-to-string table-name)))) + (query (:select (:pg_size_pretty (:pg_total_relation_size '$1))) + :single + table-name)) + + (table-size 'countries) + + "88 kB" + +#+end_src + +** Combining Postgresql Functions +:PROPERTIES: +:CUSTOM_ID: combining +:END: +#+begin_src lisp + (defun current-database-size-pretty () + "Returns the current database size as a string in MB" + (query (:select (:pg_size_pretty + (:pg_database_size (:current_database)))) + :single)) +#+end_src diff --git a/doc/s-sql-prepared-statements.html b/doc/s-sql-prepared-statements.html new file mode 100644 index 0000000..1c974ab --- /dev/null +++ b/doc/s-sql-prepared-statements.html @@ -0,0 +1,325 @@ + + + + + + +Prepared Statements + + + + + + + +
    +
    +

    Prepared Statements

    +
    + +
    +

    S-SQL Examples Home Page

    +
    + + + +++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ + + + + + + + + + + + + + + + + + + + + + + + + + + + + +
    ABCDEFGHIJKLMNOPRSTUVWSpecial CharactersCalling Postgresql Stored Functions and Procedures
    +
    +
    + +
    +

    Prepared Statements

    +
    +

    +The general rule of thumb on deciding whether to use prepared statements, is to use them unless you have sufficient reason not to. Prepared Statements are compiled before execution therefore lending to better performance, and increased security against SQL injection as the database server takes care of the encoding of special characters. +

    + +

    +Preventing SQL injection attacks. This basically means automated sanitizing of inputs from external sources (web browser is external!) which are going to be saved to the database. +Batch processing. If you have a lot of data to enter into/modify in/remove from database at once, prepared statements can be used for that. In this case, prepared statements optimize away most of the overhead of such operations and allows you to write fast database batch code. +

    +
    +
    (defprepared sovereign-of
    +    (:select 'sovereign :from 'country :where (:= 'name '$1))
    +    :single!)
    +
    +(sovereign-of "The Netherlands");; => "Beatrix"
    +
    +
    +
    +

    +The bang at the end of the :single! keyword indicates throw an error if it returns more than one. +

    +
    +
    +
    + + \ No newline at end of file diff --git a/doc/s-sql-prepared-statements.org b/doc/s-sql-prepared-statements.org new file mode 100644 index 0000000..9a2db16 --- /dev/null +++ b/doc/s-sql-prepared-statements.org @@ -0,0 +1,26 @@ +#+TITLE: Prepared Statements +#+OPTIONS: num:nil +#+HTML_HEAD: +#+HTML_HEAD: +#+OPTIONS: ^:nil + +* [[file:s-sql-examples.org][S-SQL Examples Home Page]] +| [[file:s-sql-a.org][A]]| [[file:s-sql-b.org][B]]| [[file:s-sql-c.org][C]]| [[file:s-sql-d.org][D]]| [[file:s-sql-e.org][E]]| [[file:s-sql-f.org][F]]| [[file:s-sql-g.org][G]]| [[file:s-sql-h.org][H]]| [[file:s-sql-i.org][I]]| [[file:s-sql-j.org][J]]| [[file:s-sql-k.org][K]]| [[file:s-sql-l.org][L]]| [[file:s-sql-m.org][M]]| [[file:s-sql-n.org][N]]| [[file:s-sql-o.org][O]]| [[file:s-sql-p.org][P]]| [[file:s-sql-r.org][R]]| [[file:s-sql-s.org][S]]| [[file:s-sql-t.org][T]]| [[file:s-sql-u.org][U]]| [[file:s-sql-v.org][V]]| [[file:s-sql-w.org][W]]| [[file:s-sql-special-characters.org][Special Characters]] | [[file:calling-postgresql-stored-functions.org][Calling Postgresql Stored Functions and Procedures]]| + +* Prepared Statements +:PROPERTIES: +:CUSTOM_ID: prepared-statements +:END: +The general rule of thumb on deciding whether to use prepared statements, is to use them unless you have sufficient reason not to. Prepared Statements are compiled before execution therefore lending to better performance, and increased security against SQL injection as the database server takes care of the encoding of special characters. + + Preventing SQL injection attacks. This basically means automated sanitizing of inputs from external sources (web browser is external!) which are going to be saved to the database. + Batch processing. If you have a lot of data to enter into/modify in/remove from database at once, prepared statements can be used for that. In this case, prepared statements optimize away most of the overhead of such operations and allows you to write fast database batch code. +#+begin_src lisp + (defprepared sovereign-of + (:select 'sovereign :from 'country :where (:= 'name '$1)) + :single!) + + (sovereign-of "The Netherlands");; => "Beatrix" + +#+end_src +The bang at the end of the :single! keyword indicates throw an error if it returns more than one. diff --git a/doc/s-sql-r.html b/doc/s-sql-r.html new file mode 100644 index 0000000..a3717e4 --- /dev/null +++ b/doc/s-sql-r.html @@ -0,0 +1,411 @@ + + + + + + +S-SQL Examples R + + + + + + + +
    +
    +

    S-SQL Examples R

    +
    + +
    +

    S-SQL Examples Home Page

    +
    + + + +++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ + + + + + + + + + + + + + + + + + + + + + + + + + + + + +
    ABCDEFGHIJKLMNOPRSTUVWSpecial CharactersCalling Postgresql Stored Functions and Procedures
    +
    +
    + +
    +

    Random

    +
    +
    +
    (query (:limit
    +        (:order-by
    +         (:select 'id 'name
    +                  :from 'countries)
    +         (:random))
    +        5))
    +
    +((54 "Israel") (62 "South Africa") (195 "Aruba") (79 "Costa Rica")(31 "OECD"))
    +
    +
    +
    +
    +
    + +
    +

    Raw SQL Statements

    +
    +

    +We've already seen that the postmodern:query function can take a raw sql string and that the postmodern:sql function can output an sql string. You can combine them if you need to go beyond what postmodern can already provide. Consider the following toy example which uses a part of the eventual query in the let and inserts it into the body. +

    +
    +
    (let ((param-constraints (sql (:= 'name "Austria"))))
    +  (query (:select 'id 'name
    +                  :from 'countries
    +                  :where (:raw param-constraints))))
    +
    +
    + +

    +Now consider this function where you have a conditional query based on the variables test1 and test2 passed into the function. In this toy example, if test1 is true then look for countries whose name is a fuzzy match for param1, if test2 is true, look for countries whose name is a fuzzy match for param2. If both are true, then the names need to be fuzzy matches for both param1 and param2. If neither test1 or test2 are true, then return all rows in the countries table. +

    +
    +
    (defun test3 (test1 test2 param1 param2)
    +  (query (:select '* :from 'countries
    +          :where (:and
    +                  (:raw (if test1
    +                            (sql
    +                             (:like 'name
    +                                    (concatenate 'string "%" param1
    +                                                 "%")))
    +                            "'t'"))
    +                  (:raw (if test2
    +                            (sql (:like 'name
    +                                        (concatenate 'string "%"
    +                                                     param2
    +                                                     "%")))
    +                            "'t'"))))))
    +
    +(test3 nil t "New" "gary")
    +
    +((10 "Hungary" 11 47 20 "GU" 1 "2005-09-11 00:15:40-07" "Forint" "HUF" 348))
    +
    +
    +
    +
    +
    + +
    +

    Returning the Primary Key

    +
    +

    +Suppose your table has a serial or identity key of id and you want the insert function to return the newly generated id for that new record. +

    +
    +
    (query
    + (:insert-into 'categories :set 'name "test-cat3"
    +               :returning 'id)
    + :single)
    +
    +
    +

    +The next example shows the same example using parameterized variables. +

    +
    +
    (let ((name "test-cat4"))
    +  (query
    +   (:insert-into 'categories :set 'name '$1
    +                 :returning 'id)
    +   name :single))
    +
    +
    +
    +
    + +
    +

    Rollup

    +
    +

    +Rollup was added to postgresql in version 9.5. See https://www.postgresql.org/docs/devel/static/queries-table-expressions.html#QUERIES-GROUPING-SETS Sample usage: +

    +
    +
    (query (:order-by
    +        (:select 'facid
    +                 (:as (:extract 'month 'starttime) 'month)
    +                 (:as (:sum 'slots) 'slots)
    +         :from 'cd.bookings
    +         :where (:and (:>= 'starttime "2012-01-01")
    +                      (:< 'starttime "2013-01-01"))
    +         :group-by (:rollup 'facid 'month))
    +        'facid 'month))
    +
    +
    +
    +
    +
    + + \ No newline at end of file diff --git a/doc/s-sql-r.org b/doc/s-sql-r.org new file mode 100644 index 0000000..40d92d5 --- /dev/null +++ b/doc/s-sql-r.org @@ -0,0 +1,97 @@ +#+TITLE: S-SQL Examples R +#+OPTIONS: num:nil +#+HTML_HEAD: +#+HTML_HEAD: +#+OPTIONS: ^:nil + +* [[file:s-sql-examples.org][S-SQL Examples Home Page]] +| [[file:s-sql-a.org][A]]| [[file:s-sql-b.org][B]]| [[file:s-sql-c.org][C]]| [[file:s-sql-d.org][D]]| [[file:s-sql-e.org][E]]| [[file:s-sql-f.org][F]]| [[file:s-sql-g.org][G]]| [[file:s-sql-h.org][H]]| [[file:s-sql-i.org][I]]| [[file:s-sql-j.org][J]]| [[file:s-sql-k.org][K]]| [[file:s-sql-l.org][L]]| [[file:s-sql-m.org][M]]| [[file:s-sql-n.org][N]]| [[file:s-sql-o.org][O]]| [[file:s-sql-p.org][P]]| [[file:s-sql-r.org][R]]| [[file:s-sql-s.org][S]]| [[file:s-sql-t.org][T]]| [[file:s-sql-u.org][U]]| [[file:s-sql-v.org][V]]| [[file:s-sql-w.org][W]]| [[file:s-sql-special-characters.org][Special Characters]] | [[file:calling-postgresql-stored-functions.org][Calling Postgresql Stored Functions and Procedures]]| + +* Random + :PROPERTIES: + :CUSTOM_ID: random + :END: +#+begin_src lisp + (query (:limit + (:order-by + (:select 'id 'name + :from 'countries) + (:random)) + 5)) + + ((54 "Israel") (62 "South Africa") (195 "Aruba") (79 "Costa Rica")(31 "OECD")) + +#+end_src + +* Raw SQL Statements + :PROPERTIES: + :CUSTOM_ID: raw-sql + :END: +We've already seen that the postmodern:query function can take a raw sql string and that the postmodern:sql function can output an sql string. You can combine them if you need to go beyond what postmodern can already provide. Consider the following toy example which uses a part of the eventual query in the let and inserts it into the body. +#+begin_src lisp + (let ((param-constraints (sql (:= 'name "Austria")))) + (query (:select 'id 'name + :from 'countries + :where (:raw param-constraints)))) +#+end_src + +Now consider this function where you have a conditional query based on the variables test1 and test2 passed into the function. In this toy example, if test1 is true then look for countries whose name is a fuzzy match for param1, if test2 is true, look for countries whose name is a fuzzy match for param2. If both are true, then the names need to be fuzzy matches for both param1 and param2. If neither test1 or test2 are true, then return all rows in the countries table. +#+begin_src lisp + (defun test3 (test1 test2 param1 param2) + (query (:select '* :from 'countries + :where (:and + (:raw (if test1 + (sql + (:like 'name + (concatenate 'string "%" param1 + "%"))) + "'t'")) + (:raw (if test2 + (sql (:like 'name + (concatenate 'string "%" + param2 + "%"))) + "'t'")))))) + + (test3 nil t "New" "gary") + + ((10 "Hungary" 11 47 20 "GU" 1 "2005-09-11 00:15:40-07" "Forint" "HUF" 348)) + +#+end_src + +* Returning the Primary Key + :PROPERTIES: + :CUSTOM_ID: returning-primary + :END: +Suppose your table has a serial or identity key of id and you want the insert function to return the newly generated id for that new record. +#+begin_src lisp + (query + (:insert-into 'categories :set 'name "test-cat3" + :returning 'id) + :single) +#+end_src +The next example shows the same example using parameterized variables. +#+begin_src lisp + (let ((name "test-cat4")) + (query + (:insert-into 'categories :set 'name '$1 + :returning 'id) + name :single)) +#+end_src + +* Rollup + :PROPERTIES: + :CUSTOM_ID: rollup + :END: +Rollup was added to postgresql in version 9.5. See https://www.postgresql.org/docs/devel/static/queries-table-expressions.html#QUERIES-GROUPING-SETS Sample usage: +#+begin_src lisp + (query (:order-by + (:select 'facid + (:as (:extract 'month 'starttime) 'month) + (:as (:sum 'slots) 'slots) + :from 'cd.bookings + :where (:and (:>= 'starttime "2012-01-01") + (:< 'starttime "2013-01-01")) + :group-by (:rollup 'facid 'month)) + 'facid 'month)) +#+end_src diff --git a/doc/s-sql-s.html b/doc/s-sql-s.html new file mode 100644 index 0000000..fef32d3 --- /dev/null +++ b/doc/s-sql-s.html @@ -0,0 +1,508 @@ + + + + + + +S-SQL Examples S + + + + + + + +
    +
    +

    S-SQL Examples S

    +
    + +
    +

    S-SQL Examples Home Page

    +
    + + + +++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ + + + + + + + + + + + + + + + + + + + + + + + + + + + + +
    ABCDEFGHIJKLMNOPRSTUVWSpecial CharactersCalling Postgresql Stored Functions and Procedures
    +
    +
    + +
    +

    Set

    +
    +

    +Often I need to get a list of results where a query is in a particular set. The following would be the syntax in postmodern sql where the set is a list. If you want to use a vector, then you need to use Any: +

    + +

    +The following are equivalent +

    +
    +
      (query (:select 'name
    +                  :from 'countries
    +                  :where (:in 'id
    +                              (:set 20 21 23))))
    +
    +(let ((x (list 20 21 23)))
    +  (query (:select 'name
    +                  :from 'countries
    +                  :where (:in 'id
    +                              (:set x)))))
    +
    +(query (:select 'name
    +                :from 'countries
    +                :where (:in 'id (:set (list 20 21 23)))))
    +
    +
    +
    +
    +

    Quoted lists

    +
    +

    +Replacing (list 20 21 23) with '(20 21 23) within the query will not work. Postgresql will throw a syntax error. (We have not worked out all the bugs). +

    +
    +
    (query (:select 'name
    +                :from 'countries
    +                :where (:in 'id
    +                            (:set '(20 21 23)))))
    +
    +ERROR
    +
    +
    +

    +Solution: Pass it in as a variable. +

    +
    +
    (let ((ids '(20 21 23)))
    +  (query (:select 'name
    +                :from 'countries
    +                :where (:in 'id
    +                            (:set ids)))))
    +
    +
    +

    +Now with selecting a dao +

    +
    +
    (select-dao 'countries
    +    (:in 'id
    +         (:set (list 20 21 23))))
    +
    +(#<COUNTRIES {1002B8C111}> #<COUNTRIES {1002B8C801}> #<COUNTRIES{1002B8D611}>)
    +
    +
    + +

    +Now with selecting from a vector. Note both the use of any* and := instead of :in. +#+begin_srcbbbb lisp + (let ((x (vector 20 21 23))) + (query (:select 'name + :from 'countries + :where (:= 'id (:any* x))))) +

    + +

    + (("Greece") ("US") ("UK")) +#+end_src +

    + +

    +Note that the responses are still coming back in a list of lists +

    +
    +
    +
    + +
    +

    SQL-type-name

    +
    +

    +sql-type-name is an exported generic method that allows you to define how some lisp type gets declared in sql terms that Postgresql can understand. Some examples for the built-in methods already provided will convert: +

    + + + + +++ ++ + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + +
    Lisp sampleSQL Conversion
    'float"REAL"
    '(string "5")"(CHAR(5)"
    '(string 5)"(CHAR(5)"
    'double-float"DOUBLE PRECISION"
    '(numeric 3 2)"NUMERIC(3, 2)"
    'some-symbol"SOME_SYMBOL"
    'timestamp-with-time-zone"TIMESTAMP WITH TIME ZONE"
    'timestamp-without-time-zone"TIMESTAMP WITHOUT TIME ZONE"
    + +

    +This function gets called by other operators such :create-table and :alter-table. If you need to create a conversion for e.g. some custom type for a Postgresql extension, then your method might look something like this: +

    +
    +
    (defmethod s-sql:sql-type-name ((lisp-type (eql 'pgvector)) &rest args)
    +               (cond (args (format nil "VECTOR(~{~A~^, ~})" args)))
    +                     (t "VECTOR(1)")))
    +
    +
    +

    +and then be called like this in a :create-table statement. We will use the sql function to show what the generated sql would look like: +

    +
    +
      (pomo:sql (:create-table 'items ((id :type bigserial :primary-key t)
    +                                 (embedding :type (pgvector 3)))))
    +"CREATE TABLE items (id BIGSERIAL NOT NULL PRIMARY KEY , embedding VECTOR(3) NOT NULL)"
    +
    +
    +
    +
    +
    +

    String_agg

    +
    +

    +String_agg returns a string containging the values returned, separated by a delimiter. In the following example, we are searching for the name of all the regions in the regions table and we want it all returned as a single string with a delimiting comma. +

    +
    +
    (query (:select (:string_agg 'name ",") :from 'regions))
    +
    + (("Central America,Middle East,North America,South America,Central Asia,Pacific,Caribbean,Eastern Europe,Western Europe,EMEA,APAC,LATAM,Emerging,US,Canada,Africa,All,Asia,Eastern Africa,Middle Africa,Northern Africa,Southern Africa,Western Africa,Oceania,Northern Europe,Southern Europe,Eastern Asia,South Central Asia,South East Asia"))
    +
    +
    +
    +
    +
    + +
    +

    Sum

    +
    +

    +Simple example for a sum: +

    +
    +
    (query (:select (:sum 'population) :from 'countries)
    +       :single)
    +
    +14427958899
    +
    +
    +
    +
    +
    + + \ No newline at end of file diff --git a/doc/s-sql-s.org b/doc/s-sql-s.org new file mode 100644 index 0000000..49f7f0c --- /dev/null +++ b/doc/s-sql-s.org @@ -0,0 +1,122 @@ +#+TITLE: S-SQL Examples S +#+OPTIONS: num:nil +#+HTML_HEAD: +#+HTML_HEAD: +#+OPTIONS: ^:nil + +* [[file:s-sql-examples.org][S-SQL Examples Home Page]] +| [[file:s-sql-a.org][A]]| [[file:s-sql-b.org][B]]| [[file:s-sql-c.org][C]]| [[file:s-sql-d.org][D]]| [[file:s-sql-e.org][E]]| [[file:s-sql-f.org][F]]| [[file:s-sql-g.org][G]]| [[file:s-sql-h.org][H]]| [[file:s-sql-i.org][I]]| [[file:s-sql-j.org][J]]| [[file:s-sql-k.org][K]]| [[file:s-sql-l.org][L]]| [[file:s-sql-m.org][M]]| [[file:s-sql-n.org][N]]| [[file:s-sql-o.org][O]]| [[file:s-sql-p.org][P]]| [[file:s-sql-r.org][R]]| [[file:s-sql-s.org][S]]| [[file:s-sql-t.org][T]]| [[file:s-sql-u.org][U]]| [[file:s-sql-v.org][V]]| [[file:s-sql-w.org][W]]| [[file:s-sql-special-characters.org][Special Characters]] | [[file:calling-postgresql-stored-functions.org][Calling Postgresql Stored Functions and Procedures]]| + +* Set + :PROPERTIES: + :CUSTOM_ID: set + :END: +Often I need to get a list of results where a query is in a particular set. The following would be the syntax in postmodern sql where the set is a list. If you want to use a vector, then you need to use Any: + +The following are equivalent +#+begin_src lisp + (query (:select 'name + :from 'countries + :where (:in 'id + (:set 20 21 23)))) + +(let ((x (list 20 21 23))) + (query (:select 'name + :from 'countries + :where (:in 'id + (:set x))))) + +(query (:select 'name + :from 'countries + :where (:in 'id (:set (list 20 21 23))))) +#+end_src +** Quoted lists +Replacing (list 20 21 23) with '(20 21 23) within the query will not work. Postgresql will throw a syntax error. (We have not worked out all the bugs). +#+begin_src lisp + (query (:select 'name + :from 'countries + :where (:in 'id + (:set '(20 21 23))))) + + ERROR +#+end_src +Solution: Pass it in as a variable. +#+begin_src lisp + (let ((ids '(20 21 23))) + (query (:select 'name + :from 'countries + :where (:in 'id + (:set ids))))) +#+end_src +Now with selecting a dao +#+begin_src lisp + (select-dao 'countries + (:in 'id + (:set (list 20 21 23)))) + + (# # #) +#+end_src + +Now with selecting from a vector. Note both the use of any* and := instead of :in. +#+begin_srcbbbb lisp + (let ((x (vector 20 21 23))) + (query (:select 'name + :from 'countries + :where (:= 'id (:any* x))))) + + (("Greece") ("US") ("UK")) +#+end_src + +Note that the responses are still coming back in a list of lists + +* SQL-type-name + :PROPERTIES: + :CUSTOM_ID: sql-type-name + :END: +sql-type-name is an exported generic method that allows you to define how some lisp type gets declared in sql terms that Postgresql can understand. Some examples for the built-in methods already provided will convert: + +| Lisp sample | SQL Conversion | +| 'float | "REAL" | +| '(string "5") | "(CHAR(5)" | +| '(string 5) | "(CHAR(5)" | +| 'double-float | "DOUBLE PRECISION" | +| '(numeric 3 2) | "NUMERIC(3, 2)" | +| 'some-symbol | "SOME_SYMBOL" | +| 'timestamp-with-time-zone | "TIMESTAMP WITH TIME ZONE" | +| 'timestamp-without-time-zone | "TIMESTAMP WITHOUT TIME ZONE" | + +This function gets called by other operators such :create-table and :alter-table. If you need to create a conversion for e.g. some custom type for a Postgresql extension, then your method might look something like this: +#+begin_src lisp + (defmethod s-sql:sql-type-name ((lisp-type (eql 'pgvector)) &rest args) + (cond (args (format nil "VECTOR(~{~A~^, ~})" args))) + (t "VECTOR(1)"))) +#+end_src +and then be called like this in a :create-table statement. We will use the sql function to show what the generated sql would look like: +#+begin_src lisp + (pomo:sql (:create-table 'items ((id :type bigserial :primary-key t) + (embedding :type (pgvector 3))))) +"CREATE TABLE items (id BIGSERIAL NOT NULL PRIMARY KEY , embedding VECTOR(3) NOT NULL)" +#+end_src +* String_agg + :PROPERTIES: + :CUSTOM_ID: string-agg + :END: +String_agg returns a string containging the values returned, separated by a delimiter. In the following example, we are searching for the name of all the regions in the regions table and we want it all returned as a single string with a delimiting comma. +#+begin_src lisp +(query (:select (:string_agg 'name ",") :from 'regions)) + + (("Central America,Middle East,North America,South America,Central Asia,Pacific,Caribbean,Eastern Europe,Western Europe,EMEA,APAC,LATAM,Emerging,US,Canada,Africa,All,Asia,Eastern Africa,Middle Africa,Northern Africa,Southern Africa,Western Africa,Oceania,Northern Europe,Southern Europe,Eastern Asia,South Central Asia,South East Asia")) + +#+end_src + +* Sum + :PROPERTIES: + :CUSTOM_ID: sum + :END: +Simple example for a sum: +#+begin_src lisp + (query (:select (:sum 'population) :from 'countries) + :single) + + 14427958899 +#+end_src diff --git a/doc/s-sql-special-characters.html b/doc/s-sql-special-characters.html new file mode 100644 index 0000000..f311d5d --- /dev/null +++ b/doc/s-sql-special-characters.html @@ -0,0 +1,429 @@ + + + + + + +S-SQL Special Characters + + + + + + + +
    +
    +

    S-SQL Special Characters

    +
    + +
    +

    S-SQL Examples Home Page

    +
    + + + +++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ + + + + + + + + + + + + + + + + + + + + + + + + + + + + +
    ABCDEFGHIJKLMNOPRSTUVWSpecial CharactersCalling Postgresql Stored Functions and Procedures
    + +

    +You can generally assume that most Postgresql operators will act similarly to the following: +

    +
    +
    +
    +

    := The Equal operator

    +
    +
    +
    (query (:select 'id 'name :from 'regions :where (:= 'name "South America")))
    +
    +((7 "South America"))
    +
    +
    +
    +
    + +
    +

    :+ The Plus operator

    +
    +
    +
    (query (:select (:+ 'id 12) 'name
    +                :from 'regions
    +                :where (:= 'name "South America")))
    +((19 "South America"))
    +
    +
    +
    +
    + +
    +

    :<> The Not Equals or Greater or Lesser than operators

    +
    +

    +The not equals operator +

    +
    +
    (query (:select 'id 'name
    +                :from 'regions
    +                :where (:<> 'name "Africa")))
    +
    +((3 "Central America") (5 "Middle East") (6 "North America") (7 "SouthAmerica") (8 "Central Asia") (9 "Pacific") (10 "Caribbean") (11 "Eastern Europe") (4 "Western Europe")  (2 "Asia"))
    +
    +
    +
    +
    +
    + +
    +

    :| Concatenating Columns

    +
    +

    +The concatenation operator combines two or more columns into a single column return. First, consider the query on a raw sql string: +

    +
    +
    (query "(SELECT countries.id, (countries.name | '-' | regions.name)
    +         FROM countries, regions
    +         WHERE ((regions.id = countries.region_id)
    +               and (countries.name = 'US')))")
    +
    +((21 "US-North America"))
    +
    +
    +
    + +

    +Now consider the result using s-sql. +

    +
    +
    (query (:select 'countries.id (:| 'countries.name "-" 'regions.name)
    +                :from 'countries 'regions
    +                :where (:and (:= 'regions.id 'countries.region-id)
    +                             (:= 'countries.name "US"))))
    +
    +((21 "US-North America"))
    +
    +
    +
    +
    +
    + +
    +

    :~, :!~, :~* Regex Match

    +
    +

    +Regular expression matching operators. The exclamation mark means 'does not match', +the asterisk makes the match case-insensitive. +

    +
    +
    (query (:select (:regexp_match "foobarbequebaz" "bar.*que")) :single)
    +
    +#("barbeque")
    +
    +(query (:select (:regexp_match "foobarbequebaz" "bar.~que")) :single)
    +
    +:NULL
    +
    +(query (:select (:~ "foobarbequebaz" "bar.*que") ) :single)
    +
    +t
    +
    +(query (:select (:!~ "foobarbequebaz" "bar.*que") ) :single)
    +
    +nil
    +
    +(query (:select (:~ "foobarbequebaz" "barque") ) :single)
    +
    +nil
    +
    +(query (:select (:~ "foobarbequebaz" "barbeque") ) :single)
    +
    +t
    +
    +(query (:select (:~ "foobarBequebaz" "barbeque") ) :single)
    +
    +nil
    +
    +(query (:select (:~* "foobarBequebaz" "barbeque") ) :single)
    +
    +t
    +
    +(query (:select 'id 'text :from 'text-search :where (:~ 'text "sushi")))
    +
    +
    +
    +
    +
    +
    + + \ No newline at end of file diff --git a/doc/s-sql-special-characters.org b/doc/s-sql-special-characters.org new file mode 100644 index 0000000..d2df0d3 --- /dev/null +++ b/doc/s-sql-special-characters.org @@ -0,0 +1,113 @@ +#+TITLE: S-SQL Special Characters +#+OPTIONS: num:nil +#+HTML_HEAD: +#+HTML_HEAD: +#+OPTIONS: ^:nil + +* [[file:s-sql-examples.org][S-SQL Examples Home Page]] +| [[file:s-sql-a.org][A]]| [[file:s-sql-b.org][B]]| [[file:s-sql-c.org][C]]| [[file:s-sql-d.org][D]]| [[file:s-sql-e.org][E]]| [[file:s-sql-f.org][F]]| [[file:s-sql-g.org][G]]| [[file:s-sql-h.org][H]]| [[file:s-sql-i.org][I]]| [[file:s-sql-j.org][J]]| [[file:s-sql-k.org][K]]| [[file:s-sql-l.org][L]]| [[file:s-sql-m.org][M]]| [[file:s-sql-n.org][N]]| [[file:s-sql-o.org][O]]| [[file:s-sql-p.org][P]]| [[file:s-sql-r.org][R]]| [[file:s-sql-s.org][S]]| [[file:s-sql-t.org][T]]| [[file:s-sql-u.org][U]]| [[file:s-sql-v.org][V]]| [[file:s-sql-w.org][W]]| [[file:s-sql-special-characters.org][Special Characters]] | [[file:calling-postgresql-stored-functions.org][Calling Postgresql Stored Functions and Procedures]]| + +You can generally assume that most Postgresql operators will act similarly to the following: +* := The Equal operator + :PROPERTIES: + :CUSTOM_ID: equal + :END: +#+begin_src lisp + (query (:select 'id 'name :from 'regions :where (:= 'name "South America"))) + + ((7 "South America")) +#+end_src + +* :+ The Plus operator + :PROPERTIES: + :CUSTOM_ID: plus + :END: +#+begin_src lisp + (query (:select (:+ 'id 12) 'name + :from 'regions + :where (:= 'name "South America"))) + ((19 "South America")) +#+end_src + +* :<> The Not Equals or Greater or Lesser than operators + :PROPERTIES: + :CUSTOM_ID: not-equal + :END: +The not equals operator +#+begin_src lisp + (query (:select 'id 'name + :from 'regions + :where (:<> 'name "Africa"))) + + ((3 "Central America") (5 "Middle East") (6 "North America") (7 "SouthAmerica") (8 "Central Asia") (9 "Pacific") (10 "Caribbean") (11 "Eastern Europe") (4 "Western Europe") (2 "Asia")) + +#+end_src + +* :| Concatenating Columns + :PROPERTIES: + :CUSTOM_ID: concate + :END: +The concatenation operator combines two or more columns into a single column return. First, consider the query on a raw sql string: +#+begin_src lisp + (query "(SELECT countries.id, (countries.name | '-' | regions.name) + FROM countries, regions + WHERE ((regions.id = countries.region_id) + and (countries.name = 'US')))") + + ((21 "US-North America")) + +#+end_src + +Now consider the result using s-sql. +#+begin_src lisp + (query (:select 'countries.id (:| 'countries.name "-" 'regions.name) + :from 'countries 'regions + :where (:and (:= 'regions.id 'countries.region-id) + (:= 'countries.name "US")))) + + ((21 "US-North America")) + +#+end_src + +* :~, :!~, :~* Regex Match + :PROPERTIES: + :CUSTOM_ID: regex + :END: +Regular expression matching operators. The exclamation mark means 'does not match', +the asterisk makes the match case-insensitive. +#+BEGIN_SRC lisp +(query (:select (:regexp_match "foobarbequebaz" "bar.*que")) :single) + +#("barbeque") + +(query (:select (:regexp_match "foobarbequebaz" "bar.~que")) :single) + +:NULL + +(query (:select (:~ "foobarbequebaz" "bar.*que") ) :single) + +t + +(query (:select (:!~ "foobarbequebaz" "bar.*que") ) :single) + +nil + +(query (:select (:~ "foobarbequebaz" "barque") ) :single) + +nil + +(query (:select (:~ "foobarbequebaz" "barbeque") ) :single) + +t + +(query (:select (:~ "foobarBequebaz" "barbeque") ) :single) + +nil + +(query (:select (:~* "foobarBequebaz" "barbeque") ) :single) + +t + +(query (:select 'id 'text :from 'text-search :where (:~ 'text "sushi"))) + +#+END_SRC diff --git a/doc/s-sql-t.html b/doc/s-sql-t.html new file mode 100644 index 0000000..581beef --- /dev/null +++ b/doc/s-sql-t.html @@ -0,0 +1,805 @@ + + + + + + +S-SQL Examples T + + + + + + + +
    +
    +

    S-SQL Examples T

    +
    + +
    +

    S-SQL Examples Home Page

    +
    + + + +++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ + + + + + + + + + + + + + + + + + + + + + + + + + + + + +
    ABCDEFGHIJKLMNOPRSTUVWSpecial CharactersCalling Postgresql Stored Functions and Procedures
    +
    +
    + +
    +

    Threads

    +
    +

    +While postmodern is generally thread-safe, it is up to the developer to pay attention and remember that postgresql may be spinning off processes at the same time that you are creating threads in your application. +

    + +

    +Something like taking from the postmodern/tests.lisp: +

    +
    +
    (defclass test-data ()
    +  ((id :col-type serial :initarg :id :accessor test-id)
    +   (a :col-type (or (varchar 100) db-null) :initarg :a :accessor test-a)
    +   (b :col-type boolean :col-default nil :initarg :b :accessor test-b)
    +   (c :col-type integer :col-default 0 :initarg :c :accessor test-c))
    +  (:metaclass dao-class)
    +  (:table-name dao-test)
    +  (:keys id))
    +
    +(execute (dao-table-definition 'test-data))
    +
    +(defvar *dao-update-lock* (bt:make-lock))
    +
    +(let ((item (make-instance 'test-data :a "SC" :b t :c 0)))
    +  (with-test-connection (save-dao item))
    +  (let ((id (test-id item)))
    +    (loop for x from 1 to 50 do
    +          (bt:make-thread
    +           (lambda () (with-test-connection
    +                       (loop repeat 1000 do (bt:with-lock-held (*dao-update-lock*)
    +                                                               (incf (test-c item) 1))
    +                             (save-dao item))
    +                       (loop repeat 1000 do (bt:with-lock-held (*dao-update-lock*)
    +                                                               (decf (test-c item) 1))
    +                             (save-dao item))))))
    +
    +    (with-test-connection
    +     (describe (get-dao 'test-data id)))))
    +
    +
    +
    + +

    +may return to your control before all the processes are done. As a result, if you check for value of: +

    +
    +
    (test-c (get-dao 'dao-test 1))
    +
    +
    +

    +when the lisp code returns, you may be surprised that the answer is not 0. Check a few seconds, later and it may be a different number. If you call +

    +
    +
    (pomo:list-connections)
    +
    +
    +

    +or +

    +
    +
    (query (:select '* :from 'pg-stat-activity))
    +
    +
    +

    +you may notice that there are still outstanding connection - postgresql is still working its way through the processes you just created and it will get through all of them and you will notice that the value has been finally incremented and decremented down to 0. +

    +
    +
    + +
    +

    Time Functions (now, current-timestamp, current-date, date-trunc, date-part)

    +
    +
    +
    +

    Without using local-time or simple-date

    +
    +
    +
    +

    Now

    +
    +
    +
    (query (:select (:now)) :single)
    +
    +3909564984
    +
    +
    +
    +
    +
    +

    Current-Timestamp

    +
    +
    +
    (query (:select (:current-timestamp)) :single)
    +
    +3909564895
    +
    +
    +
    +
    +
    +

    Current-Date

    +
    +
    +
    (query (:select (:current-date)) :single)
    +
    +3909513600
    +
    +
    +
    +
    +
    +

    Date-Trunc

    +
    +
    +
    (query (:select (:date-trunc "minute" (:now))) :single)
    +
    +3909566160
    +
    +
    +
    +
    + +
    +

    Date-Part

    +
    +

    +The date-part function may return a double-float, regardless of whether you are using s-sql or raw sql. +

    +
    +
    (query (:select (:date-part "year" (:now)))
    +       :single)
    +
    +2023.0d0
    +
    +
    +
    +
    +
    +

    Age

    +
    +

    +Postgresql has an Age function which generates an interval. A simple example would be: +

    +
    +
    (query "SELECT current_date,
    +       AGE(timestamp '2000-01-01')")
    +
    +((3909513600 ((:MONTHS 286) (:DAYS 20) (:SECONDS 0) (:USECONDS 0))))
    +
    +
    +
    +
    +
    +
    +

    Using Local-time library (recommended)

    +
    +

    +To use local-time load cl-postgres+local-time and then set the appropriate readers. For example: +

    +
    +
    (ql:quickload :cl-postgres+local-time)
    +(local-time:set-local-time-cl-postgres-readers)
    +
    +
    +
    +
    +

    Now

    +
    +
    +
    (query (:select (:now)) :single)
    +
    +@2023-11-21T09:18:50.623000-05:00
    +
    +(query (:select (:to-char (:now) "DY (Day), Mon (month)")) :single)
    +"TUE (Tuesday  ), Nov (november )"
    +
    +
    +
    +
    +
    +

    Current-Timestamp

    +
    +
    +
    (query (:select (:current-timestamp)) :single)
    +
    +@2023-11-21T09:20:07.254268-05:00
    +
    +
    +
    +
    +
    +

    Current-Date

    +
    +
    +
    (query (:select (:current-date)) :single)
    +
    +@2023-11-20T19:00:00.000000-05:00
    +
    +(query (:select (:current-date) (:type "now" :time)))
    +
    +((@2023-11-20T19:00:00.000000-05:00 @2000-03-01T09:21:15.756191-05:00))
    +
    +(query (:select (:to-char (:current-date) "YYYY-MM-DD HH24:MI:SS"))
    +       :single)
    +
    +"2023-11-21 00:00:00"
    +
    +(query (:select (:to-char (:current-date) "YYYY-MM-DD"))
    +       :single)
    +
    +"2023-11-21"
    +
    +
    +
    +
    +
    + +
    +

    Date-trunc

    +
    +
    +
    (query (:select (:date-trunc "minute" (:now))) :single)
    +
    +@2023-11-21T09:31:00.000000-05:00
    +
    +
    +
    +
    +
    +

    Date-part

    +
    +

    +The date-part function may return a double-float, regardless of whether you are using s-sql or raw sql. +

    +
    +
    (query (:select (:date-part "year" (:now)))
    +      :single)
    +
    +2023.0d0
    +
    +
    +
    +
    +
    +

    Age

    +
    +

    +Local-Time does not support intervals, so you could not use the Postgresql Age function with the local-time adjusted readtable. +

    +
    +
    +
    +

    Misc

    +
    +
    +
      (query (:select (:to-char
    +                 (:type "yesterday" :timestamp)
    +                 "FMMonth FMDDth"))
    +       :single)
    +
    +"November 20th"
    +
    +
    +
    +
    +
    +
    +

    Simple-date library

    +
    +

    +To use simple-date with Postmodern, load the simple-date/postgres-glue library and reset the sql readtable. For example: +

    +
    +
      (ql:quickload :simple-date/postgres-glue)
    +
    +(setf cl-postgres:*sql-readtable*
    +        (cl-postgres:copy-sql-readtable
    +            simple-date-cl-postgres-glue:*simple-date-sql-readtable*))
    +
    +
    +
    +
    +

    Now

    +
    +
    +
      (query (:select (:now)) :single)
    +
    +#<SIMPLE-DATE:TIMESTAMP 21-11-2023T14:40:08,271>
    +
    +
    +
    +
    +
    +

    Current-Timestamp

    +
    +
    +
      (query (:select (:current-timestamp)) :single)
    +
    +#<SIMPLE-DATE:TIMESTAMP 21-11-2023T14:40:59,025>
    +
    +
    +
    +
    +
    +

    Current-Date

    +
    +
    +
              (query (:select (:current-date)) :single)
    +
    +        #<SIMPLE-DATE:DATE 21-11-2023>
    +
    +         (query (:select (:current-date) (:type "now" :time)))
    +
    +    ((#<SIMPLE-DATE:DATE 21-11-2023> #<SIMPLE-DATE:TIME-OF-DAY 14:42:59.149618>))
    +
    +      (query (:select (:to-char (:current-date) "YYYY-MM-DD HH24:MI:SS"))
    +               :single)
    +
    +  "2023-11-21 00:00:00"
    +
    +    (query (:select (:to-char (:current-date) "YYYY-MM-DD"))
    +             :single)
    +"2023-11-21"
    +
    +
    +
    +
    +
    +
    +

    Date-Trunc

    +
    +
    +
      (query (:select (:date-trunc "minute" (:now)))
    +         :single)
    +
    +#<SIMPLE-DATE:TIMESTAMP 21-11-2023T14:41:00>
    +
    +
    +
    +
    + +
    +

    Date-Part

    +
    +

    +The date-part function may return a double-float, regardless of whether you are using s-sql or raw sql. +

    +
    +
      (query (:select (:date-part "year" (:now)))
    +         :single)
    +
    +2023.0d0
    +
    +
    +
    +
    (query (:select 'current-time (:type "now" :time)))
    +
    +
    +
    +
    +
    +

    Age

    +
    +

    +Simple-date does support intervals, so you can use the Postgresql Age function: +

    +
    +
      (query "SELECT current_date,
    +       AGE(timestamp '2000-01-01')")
    +((#<SIMPLE-DATE:DATE 21-11-2023> #<SIMPLE-DATE:INTERVAL P23Y10M20D>))
    +
    +
    +
    +
    +
    +
    +

    Misc

    +
    +
    +
      (query (:select (:to-char
    +                 (:type "yesterday" :timestamp)
    +                 "FMMonth FMDDth"))
    +       :single)
    +
    +"November 20th"
    +
    +
    +
    +
    +
    +
    +
    +

    To-Tsquery, To-Tsvector

    +
    +

    +First as used in creating a table: +

    +
    +
    (query (:create-table 't10
    +                      ((title :type (or text db-null))
    +                       (body :type (or text db-null))
    +                       (tsv :type (or tsvector db-null)
    +                            :generated-always
    +                            (:to-tsvector "english" 'body)))))
    +
    +
    +

    +Now in a where clause in a selection query, either specifying the language or not specifying the language.: +

    +
    +
    (query (:select 'title
    +               :from 'pgweb
    +               :where (:@@ (:to-tsvector "english" 'body)
    +                           (:to-tsquery "english" "friend"))))
    +
    +    (query (:select 'title
    +               :from 'pgweb
    +               :where (:@@ (:to-tsvector 'body)
    +                           (:to-tsquery "friend"))))
    +
    +
    +

    +S-SQL does not currently have tsquery operators, so tsquery expressions have to be included in the search term: +

    +
    +
    (query (:select 'id 'body :from 't12
    +                          :where (:@@ (:to-tsvector 'body)
    +                                      (:to-tsquery "depend | loud"))))
    +
    +
    +

    +Indexing the tsv column: +

    +
    +
    (query (:create-index 'textsearch11-idx :on 't11 :using 'gin :fields 'tsv))
    +
    +
    +
    +
    + +
    +

    Truncate

    +
    +

    +This query sql-op takes one or more table names and will truncate those tables (deleting all the rows. The following keyword parameters are optionally allowed and must be in this order. +

    +
      +
    • :only will truncate only this table and not descendent tables.
    • +
    • :restart-identity will restart any sequences owned by the table.
    • +
    • :continue-identity will continue sequences owned by the table.
    • +
    • +:cascade will cascade the truncation through tables using foreign keys. +

      +
      +
      (query (:truncate 'bigtable 'fattable))
      +(query (:truncate 'bigtable 'fattable :only))
      +(query (:truncate 'bigtable 'fattable :only :continue-identity))
      +(query (:truncate 'bigtable 'fattable :only :restart-identity))
      +(query (:truncate 'bigtable 'fattable :only :restart-identity :cascade ))
      +(query (:truncate 'bigtable 'fattable :only :continue-identity :cascade ))
      +(query (:truncate 'bigtable 'fattable :continue-identity :cascade ))
      +
      +
    • +
    +
    +
    +
    + + \ No newline at end of file diff --git a/doc/s-sql-t.org b/doc/s-sql-t.org new file mode 100644 index 0000000..9b67cc1 --- /dev/null +++ b/doc/s-sql-t.org @@ -0,0 +1,316 @@ +#+TITLE: S-SQL Examples T +#+OPTIONS: num:nil +#+HTML_HEAD: +#+HTML_HEAD: +#+OPTIONS: ^:nil + +* [[file:s-sql-examples.org][S-SQL Examples Home Page]] +| [[file:s-sql-a.org][A]]| [[file:s-sql-b.org][B]]| [[file:s-sql-c.org][C]]| [[file:s-sql-d.org][D]]| [[file:s-sql-e.org][E]]| [[file:s-sql-f.org][F]]| [[file:s-sql-g.org][G]]| [[file:s-sql-h.org][H]]| [[file:s-sql-i.org][I]]| [[file:s-sql-j.org][J]]| [[file:s-sql-k.org][K]]| [[file:s-sql-l.org][L]]| [[file:s-sql-m.org][M]]| [[file:s-sql-n.org][N]]| [[file:s-sql-o.org][O]]| [[file:s-sql-p.org][P]]| [[file:s-sql-r.org][R]]| [[file:s-sql-s.org][S]]| [[file:s-sql-t.org][T]]| [[file:s-sql-u.org][U]]| [[file:s-sql-v.org][V]]| [[file:s-sql-w.org][W]]| [[file:s-sql-special-characters.org][Special Characters]] | [[file:calling-postgresql-stored-functions.org][Calling Postgresql Stored Functions and Procedures]]| + +* Threads + :PROPERTIES: + :CUSTOM_ID: threads + :END: +While postmodern is generally thread-safe, it is up to the developer to pay attention and remember that postgresql may be spinning off processes at the same time that you are creating threads in your application. + +Something like taking from the postmodern/tests.lisp: +#+begin_src lisp +(defclass test-data () + ((id :col-type serial :initarg :id :accessor test-id) + (a :col-type (or (varchar 100) db-null) :initarg :a :accessor test-a) + (b :col-type boolean :col-default nil :initarg :b :accessor test-b) + (c :col-type integer :col-default 0 :initarg :c :accessor test-c)) + (:metaclass dao-class) + (:table-name dao-test) + (:keys id)) + +(execute (dao-table-definition 'test-data)) + +(defvar *dao-update-lock* (bt:make-lock)) + +(let ((item (make-instance 'test-data :a "SC" :b t :c 0))) + (with-test-connection (save-dao item)) + (let ((id (test-id item))) + (loop for x from 1 to 50 do + (bt:make-thread + (lambda () (with-test-connection + (loop repeat 1000 do (bt:with-lock-held (*dao-update-lock*) + (incf (test-c item) 1)) + (save-dao item)) + (loop repeat 1000 do (bt:with-lock-held (*dao-update-lock*) + (decf (test-c item) 1)) + (save-dao item)))))) + + (with-test-connection + (describe (get-dao 'test-data id))))) + +#+end_src + +may return to your control before all the processes are done. As a result, if you check for value of: +#+begin_src lisp + (test-c (get-dao 'dao-test 1)) +#+end_src +when the lisp code returns, you may be surprised that the answer is not 0. Check a few seconds, later and it may be a different number. If you call +#+begin_src lisp +(pomo:list-connections) +#+end_src +or +#+begin_src lisp +(query (:select '* :from 'pg-stat-activity)) +#+end_src +you may notice that there are still outstanding connection - postgresql is still working its way through the processes you just created and it will get through all of them and you will notice that the value has been finally incremented and decremented down to 0. + +* Time Functions (now, current-timestamp, current-date, date-trunc, date-part) + :PROPERTIES: + :CUSTOM_ID: time-functions + :END: +** Without using local-time or simple-date + :PROPERTIES: + :CUSTOM_ID: vanilla-time-functions + :END: +*** Now +#+begin_src lisp + (query (:select (:now)) :single) + + 3909564984 +#+end_src +*** Current-Timestamp +#+begin_src lisp + (query (:select (:current-timestamp)) :single) + + 3909564895 +#+end_src +*** Current-Date +#+begin_src lisp + (query (:select (:current-date)) :single) + + 3909513600 +#+end_src +*** Date-Trunc +#+begin_src lisp + (query (:select (:date-trunc "minute" (:now))) :single) + + 3909566160 +#+end_src + +*** Date-Part +The date-part function may return a double-float, regardless of whether you are using s-sql or raw sql. +#+begin_src lisp + (query (:select (:date-part "year" (:now))) + :single) + + 2023.0d0 +#+end_src +*** Age +Postgresql has an Age function which generates an interval. A simple example would be: +#+begin_src lisp + (query "SELECT current_date, + AGE(timestamp '2000-01-01')") + + ((3909513600 ((:MONTHS 286) (:DAYS 20) (:SECONDS 0) (:USECONDS 0)))) +#+end_src +** Using Local-time library (recommended) + :PROPERTIES: + :CUSTOM_ID: local-time-time-functions + :END: +To use local-time load cl-postgres+local-time and then set the appropriate readers. For example: +#+begin_src lisp + (ql:quickload :cl-postgres+local-time) + (local-time:set-local-time-cl-postgres-readers) +#+end_src +*** Now +#+begin_src lisp + (query (:select (:now)) :single) + + @2023-11-21T09:18:50.623000-05:00 + + (query (:select (:to-char (:now) "DY (Day), Mon (month)")) :single) + "TUE (Tuesday ), Nov (november )" +#+end_src +*** Current-Timestamp +#+begin_src lisp + (query (:select (:current-timestamp)) :single) + + @2023-11-21T09:20:07.254268-05:00 +#+end_src +*** Current-Date +#+begin_src lisp + (query (:select (:current-date)) :single) + + @2023-11-20T19:00:00.000000-05:00 + + (query (:select (:current-date) (:type "now" :time))) + + ((@2023-11-20T19:00:00.000000-05:00 @2000-03-01T09:21:15.756191-05:00)) + + (query (:select (:to-char (:current-date) "YYYY-MM-DD HH24:MI:SS")) + :single) + + "2023-11-21 00:00:00" + + (query (:select (:to-char (:current-date) "YYYY-MM-DD")) + :single) + + "2023-11-21" + +#+end_src + +*** Date-trunc +#+begin_src lisp +(query (:select (:date-trunc "minute" (:now))) :single) + +@2023-11-21T09:31:00.000000-05:00 +#+end_src +*** Date-part +The date-part function may return a double-float, regardless of whether you are using s-sql or raw sql. +#+begin_src lisp + (query (:select (:date-part "year" (:now))) + :single) + + 2023.0d0 +#+end_src +*** Age +Local-Time does not support intervals, so you could not use the Postgresql Age function with the local-time adjusted readtable. +*** Misc +#+begin_src lisp + (query (:select (:to-char + (:type "yesterday" :timestamp) + "FMMonth FMDDth")) + :single) + + "November 20th" +#+end_src +** Simple-date library + :PROPERTIES: + :CUSTOM_ID: simple-date-time-functions + :END: +To use simple-date with Postmodern, load the simple-date/postgres-glue library and reset the sql readtable. For example: +#+begin_src lisp + (ql:quickload :simple-date/postgres-glue) + +(setf cl-postgres:*sql-readtable* + (cl-postgres:copy-sql-readtable + simple-date-cl-postgres-glue:*simple-date-sql-readtable*)) +#+end_src +*** Now +#+begin_src lisp + (query (:select (:now)) :single) + + # +#+end_src +*** Current-Timestamp +#+begin_src lisp + (query (:select (:current-timestamp)) :single) + +# +#+end_src +*** Current-Date +#+begin_src lisp + (query (:select (:current-date)) :single) + + # + + (query (:select (:current-date) (:type "now" :time))) + + ((# #)) + + (query (:select (:to-char (:current-date) "YYYY-MM-DD HH24:MI:SS")) + :single) + + "2023-11-21 00:00:00" + + (query (:select (:to-char (:current-date) "YYYY-MM-DD")) + :single) +"2023-11-21" + +#+end_src +*** Date-Trunc +#+begin_src lisp + (query (:select (:date-trunc "minute" (:now))) + :single) + + # +#+end_src + +*** Date-Part +The date-part function may return a double-float, regardless of whether you are using s-sql or raw sql. +#+begin_src lisp + (query (:select (:date-part "year" (:now))) + :single) + +2023.0d0 +#+end_src +#+begin_src lisp +(query (:select 'current-time (:type "now" :time))) +#+end_src +*** Age +Simple-date does support intervals, so you can use the Postgresql Age function: +#+begin_src lisp + (query "SELECT current_date, + AGE(timestamp '2000-01-01')") +((# #)) + +#+end_src +*** Misc +#+begin_src lisp + (query (:select (:to-char + (:type "yesterday" :timestamp) + "FMMonth FMDDth")) + :single) + + "November 20th" +#+end_src +* To-Tsquery, To-Tsvector + :PROPERTIES: + :CUSTOM_ID: to-tsquery + :END: + First as used in creating a table: + #+begin_src lisp + (query (:create-table 't10 + ((title :type (or text db-null)) + (body :type (or text db-null)) + (tsv :type (or tsvector db-null) + :generated-always + (:to-tsvector "english" 'body))))) + #+end_src + Now in a where clause in a selection query, either specifying the language or not specifying the language.: + #+begin_src lisp + (query (:select 'title + :from 'pgweb + :where (:@@ (:to-tsvector "english" 'body) + (:to-tsquery "english" "friend")))) + + (query (:select 'title + :from 'pgweb + :where (:@@ (:to-tsvector 'body) + (:to-tsquery "friend")))) + #+end_src + S-SQL does not currently have tsquery operators, so tsquery expressions have to be included in the search term: + #+begin_src lisp + (query (:select 'id 'body :from 't12 + :where (:@@ (:to-tsvector 'body) + (:to-tsquery "depend | loud")))) + #+end_src + Indexing the tsv column: + #+begin_src lisp + (query (:create-index 'textsearch11-idx :on 't11 :using 'gin :fields 'tsv)) + #+end_src + +* Truncate + :PROPERTIES: + :CUSTOM_ID: truncate + :END: +This query sql-op takes one or more table names and will truncate those tables (deleting all the rows. The following keyword parameters are optionally allowed and must be in this order. +- :only will truncate only this table and not descendent tables. +- :restart-identity will restart any sequences owned by the table. +- :continue-identity will continue sequences owned by the table. +- :cascade will cascade the truncation through tables using foreign keys. + #+begin_src lisp + (query (:truncate 'bigtable 'fattable)) + (query (:truncate 'bigtable 'fattable :only)) + (query (:truncate 'bigtable 'fattable :only :continue-identity)) + (query (:truncate 'bigtable 'fattable :only :restart-identity)) + (query (:truncate 'bigtable 'fattable :only :restart-identity :cascade )) + (query (:truncate 'bigtable 'fattable :only :continue-identity :cascade )) + (query (:truncate 'bigtable 'fattable :continue-identity :cascade )) + #+end_src diff --git a/doc/s-sql-u.html b/doc/s-sql-u.html new file mode 100644 index 0000000..b41f2bb --- /dev/null +++ b/doc/s-sql-u.html @@ -0,0 +1,565 @@ + + + + + + +S-SQL Examples U + + + + + + + +
    +
    +

    S-SQL Examples U

    +
    + +
    +

    S-SQL Examples Home Page

    +
    + + + +++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ + + + + + + + + + + + + + + + + + + + + + + + + + + + + +
    ABCDEFGHIJKLMNOPRSTUVWSpecial CharactersCalling Postgresql Stored Functions and Procedures
    +
    +
    + +
    +

    Union, Union-all

    +
    +

    +As you probably know, the union operation generally eliminates what it thinks are duplicate rows. The union-all operation preserves duplicate rows. The examples below use the union-all operator, but the syntax would be the same with union. +

    +
    +
    (query (:select 'id 'name
    +                :from (:as (:union-all
    +                            (:select 'id 'name
    +                                     :from 'countries
    +                                     :where (:<= 'name "B" ))
    +                            (:select 'id 'name
    +                                     :from 'countries
    +                                     :where (:>= 'name "V" )))
    +                           'a)))
    +
    +((140 "Algeria") (83 "American Samoa") (202 "Angola") (45 "Argentina")(195 "Aruba") (38 "Australia") (1 "Austria") (117 "Azerbaijan") (121 "Antigua") (34 "All") (130 "Albania") (127 "Armenia") (82 "Afghanistan") (142 "Zimbabwe") (43 "Worldwide") (66 "Venezuela") (111 "Vanuatu") (115 "Wallis") (141 "Zambia") (68 "Vietnam") (212 "Yemen")(215 "test6"))
    +
    +(query (:select 'a.id 'a.name 'a.region
    +        :from (:as (:union-all
    +                    (:select 'countries.id 'countries.name
    +                             (:as 'regions.name 'region)
    +                     :from 'countries 'regions
    +                             :where (:and
    +                                     (:<= 'countries.name "B")
    +                                     (:= 'regions.id 'countries.region-id)))
    +                    (:select 'countries.id 'countries.name
    +                             (:as 'regions.name 'region)
    +                     :from 'countries 'regions
    +                             :where (:and
    +                                     (:>= 'countries.name "V")
    +                                     (:= 'regions.id 'countries.region-id ))))
    +                   'a)
    +        :group-by 'a.id 'a.region 'a.name))
    +
    +((140 "Algeria" "Africa") (1 "Austria" "Western Europe")   (68 "Vietnam"  "Asia") (83 "American Samoa" "Pacific")   (202 "Angola""Africa") (121  "Antigua" "Caribbean")  (127 "Armenia" "Eastern  Europe") (66 "Venezuela""South America")   (45  "Argentina" "South  America") (195 "Aruba""Caribbean")   (38  "Australia" "Pacific")(82 "Afghanistan" "Asia")   (130 "Albania" "Eastern Europe") (111 "Vanuatu" "Pacific")  (212 "Yemen" "Middle East") (115 "Wallis"  "Pacific")   (142 "Zimbabwe" "Africa")  (117 "Azerbaijan" "Easter Europe")   (141 "Zambia" "Africa"))
    +
    +
    +
    +
    +
    + +
    +

    Unique

    +
    +

    +Unique is a constraint used in creating tables. Note the use in the following query used to build the regions table. +

    +
    +
    (query (:create-table regions
    +                      ((id :type int4 :primary-key t)
    +                       (name :type varchar :default "" :unique t))))
    +
    +
    +
    +
    + + +
    +

    Update

    +
    +

    +In s-sql, updates operate the way you would expect them to, given what we have seen up above. +

    +
    +
    (query (:update 'countries :set 'text '$1 :where (:= 'id 284)) "now")
    +
    +
    + +

    +Now temporarily assume that we do not have a normalized database and we have a field "region_name" in the countries table in the database and a slot accessor named region-name in the countries class. +

    + +

    +We could update a set of the countries rows to get the regional names for a particular set of countries, given a list of countries.id as follows: +

    +
    +
    (query
    + (:update 'countries
    +  :set 'region-name
    +          (:select 'name :from 'regions
    +           :where (:= 'countries.id 'country-id))
    +          :where (:in 'countries.id
    +                      (:set 129 139 132 128 135 134 131 137 130 133 136))))
    +
    +
    +
    + +

    +Assume you wanted to update a record with id=5 and you had a plist of the the columns to be updated. +

    + +

    +Assuming you wanted to create something reusable, you could use a query like the following: +

    +
    +
    (query
    + (sql-compile (append (append `(:update ,table :set)
    +                              plst)
    +                      `(:where (:= 'id ,id)))))
    +
    +
    + +

    +You can use the RETURNING keyword to return all or parts of the updated entries. +

    +
    +
    (query (sql (:update 'weather
    +             :set 'temp-lo (:+ 'temp-lo 1) 'temp-hi (:+ 'temp-lo 15) 'prcp :default
    +                     :where (:and (:= 'city "San Francisco")
    +                                  (:= 'date "2003-07-03"))
    +                     :returning 'temp-lo 'temp-hi 'prcp))
    +
    +
    +
    + +
    +

    Alternative Column list Syntax

    +
    +

    +Use the alternative column-list syntax to do the same update: +

    +
    +
    (query (:update 'weather
    +        :columns 'temp-lo 'temp-hi 'prcp
    +                (:set (:+ 'temp-lo 1)  (:+ 'temp-lo 15)  :DEFAULT)
    +                :where (:and (:= 'city "San Francisco")
    +                             (:= 'date "2003-07-03"))))
    +
    +
    +
    +
    + + +
    +

    Single New Value for Multiple Rows

    +
    +

    +When you need to update lots of rows, a single call to the database is often more efficient, but what that call looks like will depend on your data. If you have a single value that needs to be inserted into multiple rows, you just need to manage the condition clause. To create a silly example, suppose we want to change the intermediate_region_name in the regions table to "Too Close to the UK" instead of "Channel Islands". Here are three different ways to do that +

    +
    +
    (query (:update 'regions
    +        :set 'intermediate-region-name "Too Close to the UK"
    +        :where (:= 'intermediate-region-name "Channel Islands")))
    +
    +(query (:update 'regions
    +        :set 'intermediate-region-name "Too Close to the UK"
    +        :where (:in 'id (:set 179 180))))
    +
    +(query (:update 'regions
    +        :set 'intermediate-region-name "Too Close to the UK"
    +        :where (:or (:= 'country "Guernsey")
    +                    (:= 'country "Jersey"))))
    +
    +
    +
    +
    +
    + +
    +

    Using a Case Statement

    +
    +

    +If you have a limited number of situations with a different value for each situation, you can reach for a case statement. +

    + +

    +Staying with silly renames of intermediate_region_names, suppose we want "Caribbean" to be "Warm Island Americas" (thus excluding Bermuda) and "Central America" to be "Connecting Bridge Americas". One form of the case statement accomplishing this could look like this: +

    +
    +
    (query (:update 'regions
    +        :set 'intermediate-region-name
    +              (:case ((:= 'intermediate-region-name "Caribbean")
    +                       "Warm Island Americas")
    +                     ((:= 'intermediate-region-name "Central America")
    +                       "Connecting Bridge Americas"))
    +         :where (:in 'intermediate-region-name
    +                   (:set "Caribbean" "Central America"))))
    +
    +
    +
    +
    + +
    +

    Pulling Updated Info From Another Table

    +
    +
    +
    (query (:update 'geo
    +        :set 'iso3 'regions.iso3
    +        :from 'regions
    +        :where (:= 'regions.iso2 'geo.iso3)))
    +
    +
    +
    +
    +
    + +
    +

    Upsert or "On Conflict"

    +
    +

    +Some people use the term "upsert" for trying to insert a new row, but if that record already exists, then either update the row with new values or do nothing (as opposed to throwing an error). +

    + +

    +Beginning in Postgresql versions 9.5 and above, it is possible to use what Postgresql calls on-conflict. There are two versions - "on conflict do nothing" or "on conflict update". See below for sample call in postmodern for on-conflict-update. +

    +
    +
    (query (:insert-into 'test-table :set 'column-A '$1 'column-B '$2
    +                     :on-conflict-update 'column-A
    +                     :update-set 'column-B '$2
    +                     :where (:= 'test-table.column-A '$1)) "c" 37)
    +
    +
    + +

    +Or +

    +
    +
    (query (:select 'countries.name :from 'countries 'regions
    +                               :where (:and (:or (:= 'regions.name "North America")
    +                                            (:= 'regions.name "Central America"))
    +                                             (:= 'regions.id 'countries.region-id))))
    +
    +
    +
    +
    +
    + +
    +

    Using

    +
    +

    +From the postgresql docs: "USING is a shorthand notation: it takes a comma-separated list of column names, which the joined tables must have in common, and forms a join condition specifying equality of each of these pairs of columns. Furthermore, the output of JOIN USING has one column for each of the equated pairs of input columns, followed by the remaining columns from each table. Thus, USING (a, b, c) is equivalent to ON (t1.a = t2.a AND t1.b = t2.b AND t1.c = t2.c) with the exception that if ON is used there will be two columns a, b, and c in the result, whereas with USING there will be only one of each (and they will appear first if SELECT * is used). +

    + +

    +Example: Sorry, real toy example here. We assume an additional table named "countries-topics" and that both countries-topics and countries have columns named country-id. We are looking for records from the countries table which do not have a match in the countries-topics table. In other words, where do we have a note, but not matched it to a topic? The difference between ":using" and ":on" is the requirement that both tables have columns with the same names. You could join using multiple columns, just adding them into the parenthetical following the keyword :using. +

    +
    +
    (defun countries-with-no-topics ()
    +  (query (:order-by
    +          (:select 'countries.id 'countries.name
    +                   :distinct
    +                   :from 'countries
    +                   :left-join 'countries-topics
    +                   :using ('country-id)
    +                   :where (:is-null 'countries-topics.country-id))
    +          'countries.country-id)))
    +
    +
    +
    +
    +
    + + \ No newline at end of file diff --git a/doc/s-sql-u.org b/doc/s-sql-u.org new file mode 100644 index 0000000..0de59c6 --- /dev/null +++ b/doc/s-sql-u.org @@ -0,0 +1,207 @@ +#+TITLE: S-SQL Examples U +#+OPTIONS: num:nil +#+HTML_HEAD: +#+HTML_HEAD: +#+OPTIONS: ^:nil + +* [[file:s-sql-examples.org][S-SQL Examples Home Page]] +| [[file:s-sql-a.org][A]]| [[file:s-sql-b.org][B]]| [[file:s-sql-c.org][C]]| [[file:s-sql-d.org][D]]| [[file:s-sql-e.org][E]]| [[file:s-sql-f.org][F]]| [[file:s-sql-g.org][G]]| [[file:s-sql-h.org][H]]| [[file:s-sql-i.org][I]]| [[file:s-sql-j.org][J]]| [[file:s-sql-k.org][K]]| [[file:s-sql-l.org][L]]| [[file:s-sql-m.org][M]]| [[file:s-sql-n.org][N]]| [[file:s-sql-o.org][O]]| [[file:s-sql-p.org][P]]| [[file:s-sql-r.org][R]]| [[file:s-sql-s.org][S]]| [[file:s-sql-t.org][T]]| [[file:s-sql-u.org][U]]| [[file:s-sql-v.org][V]]| [[file:s-sql-w.org][W]]| [[file:s-sql-special-characters.org][Special Characters]] | [[file:calling-postgresql-stored-functions.org][Calling Postgresql Stored Functions and Procedures]]| + +* Union, Union-all + :PROPERTIES: + :CUSTOM_ID: union + :END: +As you probably know, the union operation generally eliminates what it thinks are duplicate rows. The union-all operation preserves duplicate rows. The examples below use the union-all operator, but the syntax would be the same with union. +#+begin_src lisp + (query (:select 'id 'name + :from (:as (:union-all + (:select 'id 'name + :from 'countries + :where (:<= 'name "B" )) + (:select 'id 'name + :from 'countries + :where (:>= 'name "V" ))) + 'a))) + + ((140 "Algeria") (83 "American Samoa") (202 "Angola") (45 "Argentina")(195 "Aruba") (38 "Australia") (1 "Austria") (117 "Azerbaijan") (121 "Antigua") (34 "All") (130 "Albania") (127 "Armenia") (82 "Afghanistan") (142 "Zimbabwe") (43 "Worldwide") (66 "Venezuela") (111 "Vanuatu") (115 "Wallis") (141 "Zambia") (68 "Vietnam") (212 "Yemen")(215 "test6")) + + (query (:select 'a.id 'a.name 'a.region + :from (:as (:union-all + (:select 'countries.id 'countries.name + (:as 'regions.name 'region) + :from 'countries 'regions + :where (:and + (:<= 'countries.name "B") + (:= 'regions.id 'countries.region-id))) + (:select 'countries.id 'countries.name + (:as 'regions.name 'region) + :from 'countries 'regions + :where (:and + (:>= 'countries.name "V") + (:= 'regions.id 'countries.region-id )))) + 'a) + :group-by 'a.id 'a.region 'a.name)) + + ((140 "Algeria" "Africa") (1 "Austria" "Western Europe") (68 "Vietnam" "Asia") (83 "American Samoa" "Pacific") (202 "Angola""Africa") (121 "Antigua" "Caribbean") (127 "Armenia" "Eastern Europe") (66 "Venezuela""South America") (45 "Argentina" "South America") (195 "Aruba""Caribbean") (38 "Australia" "Pacific")(82 "Afghanistan" "Asia") (130 "Albania" "Eastern Europe") (111 "Vanuatu" "Pacific") (212 "Yemen" "Middle East") (115 "Wallis" "Pacific") (142 "Zimbabwe" "Africa") (117 "Azerbaijan" "Easter Europe") (141 "Zambia" "Africa")) + +#+end_src + +* Unique + :PROPERTIES: + :CUSTOM_ID: unique + :END: +Unique is a constraint used in creating tables. Note the use in the following query used to build the regions table. +#+begin_src lisp + (query (:create-table regions + ((id :type int4 :primary-key t) + (name :type varchar :default "" :unique t)))) +#+end_src + + +* Update + :PROPERTIES: + :CUSTOM_ID: update + :END: +In s-sql, updates operate the way you would expect them to, given what we have seen up above. +#+begin_src lisp +(query (:update 'countries :set 'text '$1 :where (:= 'id 284)) "now") +#+end_src + +Now temporarily assume that we do not have a normalized database and we have a field "region_name" in the countries table in the database and a slot accessor named region-name in the countries class. + +We could update a set of the countries rows to get the regional names for a particular set of countries, given a list of countries.id as follows: +#+begin_src lisp + (query + (:update 'countries + :set 'region-name + (:select 'name :from 'regions + :where (:= 'countries.id 'country-id)) + :where (:in 'countries.id + (:set 129 139 132 128 135 134 131 137 130 133 136)))) + +#+end_src + +Assume you wanted to update a record with id=5 and you had a plist of the the columns to be updated. + +Assuming you wanted to create something reusable, you could use a query like the following: +#+begin_src lisp + (query + (sql-compile (append (append `(:update ,table :set) + plst) + `(:where (:= 'id ,id))))) +#+end_src + + You can use the RETURNING keyword to return all or parts of the updated entries. +#+begin_src lisp + (query (sql (:update 'weather + :set 'temp-lo (:+ 'temp-lo 1) 'temp-hi (:+ 'temp-lo 15) 'prcp :default + :where (:and (:= 'city "San Francisco") + (:= 'date "2003-07-03")) + :returning 'temp-lo 'temp-hi 'prcp)) +#+end_src + +** Alternative Column list Syntax + :PROPERTIES: + :CUSTOM_ID: alternative-column-list + :END: +Use the alternative column-list syntax to do the same update: +#+begin_src lisp + (query (:update 'weather + :columns 'temp-lo 'temp-hi 'prcp + (:set (:+ 'temp-lo 1) (:+ 'temp-lo 15) :DEFAULT) + :where (:and (:= 'city "San Francisco") + (:= 'date "2003-07-03")))) +#+end_src + + +** Single New Value for Multiple Rows + :PROPERTIES: + :CUSTOM_ID: single-value + :END: +When you need to update lots of rows, a single call to the database is often more efficient, but what that call looks like will depend on your data. If you have a single value that needs to be inserted into multiple rows, you just need to manage the condition clause. To create a silly example, suppose we want to change the intermediate_region_name in the regions table to "Too Close to the UK" instead of "Channel Islands". Here are three different ways to do that +#+begin_src lisp +(query (:update 'regions + :set 'intermediate-region-name "Too Close to the UK" + :where (:= 'intermediate-region-name "Channel Islands"))) + +(query (:update 'regions + :set 'intermediate-region-name "Too Close to the UK" + :where (:in 'id (:set 179 180)))) + +(query (:update 'regions + :set 'intermediate-region-name "Too Close to the UK" + :where (:or (:= 'country "Guernsey") + (:= 'country "Jersey")))) + +#+end_src + +** Using a Case Statement + :PROPERTIES: + :CUSTOM_ID: using-case + :END: +If you have a limited number of situations with a different value for each situation, you can reach for a case statement. + +Staying with silly renames of intermediate_region_names, suppose we want "Caribbean" to be "Warm Island Americas" (thus excluding Bermuda) and "Central America" to be "Connecting Bridge Americas". One form of the case statement accomplishing this could look like this: +#+begin_src lisp +(query (:update 'regions + :set 'intermediate-region-name + (:case ((:= 'intermediate-region-name "Caribbean") + "Warm Island Americas") + ((:= 'intermediate-region-name "Central America") + "Connecting Bridge Americas")) + :where (:in 'intermediate-region-name + (:set "Caribbean" "Central America")))) +#+end_src + +** Pulling Updated Info From Another Table + :PROPERTIES: + :CUSTOM_ID: from-another-table + :END: +#+begin_src lisp +(query (:update 'geo + :set 'iso3 'regions.iso3 + :from 'regions + :where (:= 'regions.iso2 'geo.iso3))) +#+end_src + +* Upsert or "On Conflict" + :PROPERTIES: + :CUSTOM_ID: upsert + :END: +Some people use the term "upsert" for trying to insert a new row, but if that record already exists, then either update the row with new values or do nothing (as opposed to throwing an error). + +Beginning in Postgresql versions 9.5 and above, it is possible to use what Postgresql calls on-conflict. There are two versions - "on conflict do nothing" or "on conflict update". See below for sample call in postmodern for on-conflict-update. +#+begin_src lisp +(query (:insert-into 'test-table :set 'column-A '$1 'column-B '$2 + :on-conflict-update 'column-A + :update-set 'column-B '$2 + :where (:= 'test-table.column-A '$1)) "c" 37) +#+end_src + +Or +#+begin_src lisp +(query (:select 'countries.name :from 'countries 'regions + :where (:and (:or (:= 'regions.name "North America") + (:= 'regions.name "Central America")) + (:= 'regions.id 'countries.region-id)))) + +#+end_src + +* Using + :PROPERTIES: + :CUSTOM_ID: using + :END: +From the postgresql docs: "USING is a shorthand notation: it takes a comma-separated list of column names, which the joined tables must have in common, and forms a join condition specifying equality of each of these pairs of columns. Furthermore, the output of JOIN USING has one column for each of the equated pairs of input columns, followed by the remaining columns from each table. Thus, USING (a, b, c) is equivalent to ON (t1.a = t2.a AND t1.b = t2.b AND t1.c = t2.c) with the exception that if ON is used there will be two columns a, b, and c in the result, whereas with USING there will be only one of each (and they will appear first if SELECT * is used). + +Example: Sorry, real toy example here. We assume an additional table named "countries-topics" and that both countries-topics and countries have columns named country-id. We are looking for records from the countries table which do not have a match in the countries-topics table. In other words, where do we have a note, but not matched it to a topic? The difference between ":using" and ":on" is the requirement that both tables have columns with the same names. You could join using multiple columns, just adding them into the parenthetical following the keyword :using. +#+begin_src lisp +(defun countries-with-no-topics () + (query (:order-by + (:select 'countries.id 'countries.name + :distinct + :from 'countries + :left-join 'countries-topics + :using ('country-id) + :where (:is-null 'countries-topics.country-id)) + 'countries.country-id))) +#+end_src diff --git a/doc/s-sql-v.html b/doc/s-sql-v.html new file mode 100644 index 0000000..0825101 --- /dev/null +++ b/doc/s-sql-v.html @@ -0,0 +1,347 @@ + + + + + + +S-SQL Examples V + + + + + + + +
    +
    +

    S-SQL Examples V

    +
    + +
    +

    S-SQL Examples Home Page

    +
    + + + +++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ + + + + + + + + + + + + + + + + + + + + + + + + + + + + +
    ABCDEFGHIJKLMNOPRSTUVWSpecial CharactersCalling Postgresql Stored Functions and Procedures
    +
    +
    + +
    +

    Variable Parameters

    +
    +

    +You can use variables in s-sql statements. For example: +

    +
    +
    (let ((column 'latitude) (table 'countries))
    +             (query (:select column :from table)))
    +
    +(let ((select 'countries.name))
    +             (query (:select select
    +                   :from 'countries 'regions
    +                   :where (:and
    +                           (:or (:= 'regions.name '$1)
    +                                (:= 'regions.name '$2))
    +                           (:= 'regions.id 'countries.region-id)))))
    +
    +
    +

    +Notice that the variable values were quoted. If you used strings, the string would be escaped and Postgresql would give you a syntax error. +

    +
    +
    + +
    +

    View (:create-view)

    +
    +

    +Create-view will accept quoted values, strings or keywords for the name of the view you are creating. Hyphens will be automatically be converted to underscores. +

    +
    +
    (query (:create-view 'quagmire (:select 'id 'name :from 'employee)))
    +
    +(query (:create-view :quagmire (:select 'id 'name :from 'employee)))
    +
    +(query (:create-view "quagmire" (:select 'id 'name :from 'employee)))
    +
    +(query (:create-view 'quagmire-hollow (:select 'id 'name :from 'employee)))
    +
    +(query (:create-view "quagmire-hollow" (:select 'id 'name :from 'employee)))
    +
    +
    +
    +
    +
    +
    + + \ No newline at end of file diff --git a/doc/s-sql-v.org b/doc/s-sql-v.org new file mode 100644 index 0000000..af58e17 --- /dev/null +++ b/doc/s-sql-v.org @@ -0,0 +1,45 @@ +#+TITLE: S-SQL Examples V +#+OPTIONS: num:nil +#+HTML_HEAD: +#+HTML_HEAD: +#+OPTIONS: ^:nil + +* [[file:s-sql-examples.org][S-SQL Examples Home Page]] +| [[file:s-sql-a.org][A]]| [[file:s-sql-b.org][B]]| [[file:s-sql-c.org][C]]| [[file:s-sql-d.org][D]]| [[file:s-sql-e.org][E]]| [[file:s-sql-f.org][F]]| [[file:s-sql-g.org][G]]| [[file:s-sql-h.org][H]]| [[file:s-sql-i.org][I]]| [[file:s-sql-j.org][J]]| [[file:s-sql-k.org][K]]| [[file:s-sql-l.org][L]]| [[file:s-sql-m.org][M]]| [[file:s-sql-n.org][N]]| [[file:s-sql-o.org][O]]| [[file:s-sql-p.org][P]]| [[file:s-sql-r.org][R]]| [[file:s-sql-s.org][S]]| [[file:s-sql-t.org][T]]| [[file:s-sql-u.org][U]]| [[file:s-sql-v.org][V]]| [[file:s-sql-w.org][W]]| [[file:s-sql-special-characters.org][Special Characters]] | [[file:calling-postgresql-stored-functions.org][Calling Postgresql Stored Functions and Procedures]]| + +* Variable Parameters + :PROPERTIES: + :CUSTOM_ID: variable-parameters + :END: +You can use variables in s-sql statements. For example: +#+begin_src lisp + (let ((column 'latitude) (table 'countries)) + (query (:select column :from table))) + + (let ((select 'countries.name)) + (query (:select select + :from 'countries 'regions + :where (:and + (:or (:= 'regions.name '$1) + (:= 'regions.name '$2)) + (:= 'regions.id 'countries.region-id))))) + #+end_src + Notice that the variable values were quoted. If you used strings, the string would be escaped and Postgresql would give you a syntax error. + +* View (:create-view) + :PROPERTIES: + :CUSTOM_ID: create-view + :END: +Create-view will accept quoted values, strings or keywords for the name of the view you are creating. Hyphens will be automatically be converted to underscores. +#+begin_src lisp + (query (:create-view 'quagmire (:select 'id 'name :from 'employee))) + + (query (:create-view :quagmire (:select 'id 'name :from 'employee))) + + (query (:create-view "quagmire" (:select 'id 'name :from 'employee))) + + (query (:create-view 'quagmire-hollow (:select 'id 'name :from 'employee))) + + (query (:create-view "quagmire-hollow" (:select 'id 'name :from 'employee))) + +#+end_src diff --git a/doc/s-sql-w.html b/doc/s-sql-w.html new file mode 100644 index 0000000..01ad924 --- /dev/null +++ b/doc/s-sql-w.html @@ -0,0 +1,472 @@ + + + + + + +S-SQL Examples W + + + + + + + +
    +
    +

    S-SQL Examples W

    +
    + +
    +

    S-SQL Examples Home Page

    +
    + + + +++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ ++ + + + + + + + + + + + + + + + + + + + + + + + + + + + + +
    ABCDEFGHIJKLMNOPRSTUVWSpecial CharactersCalling Postgresql Stored Functions and Procedures
    +
    +
    + +
    +

    When

    +
    +
    +
    (let ((param-latitude nil) (param-longitude t))
    +  (query (:select 'id 'name
    +                  (when param-latitude '0)
    +                  (when param-longitude 'longitude)
    +                  :from 'countries
    +                  :where (:= 'id 20))))
    +
    +((20 "UK" NIL -2))
    +
    +
    +
    +
    + +
    +

    Window

    +
    +

    +As stated in the postgresql documentation: "When a query involves multiple window functions, it is possible to write out each one with a separate OVER clause, but this is duplicative and error-prone if the same windowing behavior is wanted for several functions. Instead, each windowing behavior can be named in a WINDOW clause and then referenced in OVER". http://www.postgresql.org/docs/9.1/static/tutorial-window.html. They are available in postmodern as of the 29 October 2013 additions to the git repository. +

    +
    +
    (query (:select (:over (:sum 'salary) 'w)
    +                (:over (:avg 'salary) 'w)
    +                :from 'empsalary :window
    +                (:as 'w (:partition-by 'depname :order-by (:desc 'salary)))))
    +
    +
    +
    +
    + +
    +

    With

    +
    +

    +With queries are often referred to as Common Table Expressions. They are used as ways to write auxiliary statements for use in a larger query. The Postgresql documentation covers them at http://www.postgresql.org/docs/current/queries-with.html +

    +
    +
    (query
    + (:with
    +  (:as 'upd
    +       (:parens
    +        (:update 'employees
    +         :set 'sales-count (:= 'sales-count 1)
    +                 :where (:= 'id
    +                            (:select 'sales-person
    +                             :from 'accounts
    +                             :where (:= 'name "Acme Corporation")))
    +                 :returning '*)))
    +  (:insert-into 'employees-log
    +                (:select '* 'current-timestamp
    +                         :from
    +                         'upd))))
    +
    +
    +
    +
    + +
    +

    With-recursive

    +
    +

    +With-recursive allows the with auxiliary statement to refer to itself. These queries match the following template: +

    +
    +
    WITH RECURSIVE [temp table] [column list]
    +AS (   [seed statement]
    +UNION ALL   [recursive statement - effectively looping through the table] )
    +
    +[outer query which specifies the fields to be kept in the final result and throws away the intermediate results]
    +
    +
    +
    +

    +Testing with recursive. When working with recursive queries it is important to be sure that the recursive part of the query will eventually return no tuples, or else the query will loop indefinitely. Sometimes, using UNION instead of UNION ALL can accomplish this by discarding rows that duplicate previous output rows. However, often a cycle does not involve output rows that are completely duplicate: it may be necessary to check just one or a few fields to see if the same point has been reached before. The standard method for handling such situations is to compute an array of the already-visited values. +

    + +

    +A few postmodern samples follow which match up with the postgresql documentation examples: +

    +
    +
    (query
    + (:with-recursive
    +     (:as (:t1 'n)
    +          (:union-all (:values (:set 1))
    +                      (:select (:+ 'n 1)
    +                       :from 't1
    +                       :where (:< 'n 100))))
    +   (:select (:sum 'n) :from 't1))
    + :single))
    +
    +(query
    + (:with-recursive
    +     (:as (:included-parts 'sub-part 'part 'quantity)
    +          (:union-all
    +           (:select 'sub-part 'part 'quantity
    +            :from 'parts
    +            :where (:= 'part "our-product"))
    +           (:select 'p.sub-part 'p.part 'p.quantity
    +            :from (:as 'included-parts 'pr)
    +                    (:as 'parts 'p)
    +                    :where (:= 'p.part 'pr.sub-part))))
    +   (:select 'sub-part (:as (:sum 'quantity) 'total-quantity)
    +            :from 'included-parts
    +            :group-by 'sub-part)))
    +
    +
    +(query
    + (:with-recursive
    +     (:as (:search-graph 'id 'link 'data 'depth)
    +          (:union-all
    +           (:select 'g.id 'g.link 'g.data 1
    +                    :from (:as 'graph 'g))
    +           (:select 'g.id 'g.link 'g.data (:= 'sg.depth 1)
    +                    :from (:as 'graph 'g) (:as 'search-graph 'sg)
    +            :where (:= 'g.id 'sg.link))))
    +   (:select '* :from 'search-graph)))
    +
    +(query
    + (:with-recursive
    +     (:as (:search-graph 'id 'link 'data'depth 'path 'cycle)
    +          (:union-all
    +           (:select 'g.id 'g.link 'g.data 1
    +                    (:[] 'g.f1 'g.f2) nil
    +                    :from (:as 'graph 'g))
    +           (:select 'g.id 'g.link 'g.data (:= 'sg.depth 1)
    +                    (:|| 'path (:row 'g.f1 'g.f2))
    +                    (:= (:row 'g.f1 'g.f2)
    +                        (:any* 'path))
    +                    :from (:as 'graph 'g)
    +                    (:as 'search-graph 'sg)
    +            :where (:and (:= 'g.id 'sg.link)
    +                         (:not 'cycle)))))
    +   (:select '* :from 'search-graph)))
    +
    +
    +
    + +

    +As a different example, consider a quicklisp dependency table where the fields are 'depends_on' and 'depended_on'. In other words library staple depends-on alexandria. So one record has "staple" in the depends_on column and "alexandria" in the depended_on column. +

    + +

    +A function to return a list of all the dependencies of a quicklisp library (assuming the data is in a table called "dependencies") could look like this: +

    +
    +
    (defun list-dependencies (lib-name)
    +  "Returns a list of the names of the direct and indirect libraries depended-on by lib-name."
    +  (sort (alexandria:flatten
    +           (postmodern:query
    +            (:with-recursive
    +            (:as 'children
    +                 (:union
    +                  (:select 'depended-on
    +                           :from 'dependencies
    +                           :where (:= 'depends-on '$1))
    +                  (:select 'a.depended-on
    +                           :from (:as 'dependencies 'a)
    +                           :inner-join (:as 'children 'b)
    +                           :on (:= 'a.depends-on 'b.depended-on))))
    +            (:select '* :from 'children))
    +            lib-name))
    +      #'string<)))
    +
    +
    +
    +
    +
    + + \ No newline at end of file diff --git a/doc/s-sql-w.org b/doc/s-sql-w.org new file mode 100644 index 0000000..330c58e --- /dev/null +++ b/doc/s-sql-w.org @@ -0,0 +1,154 @@ +#+TITLE: S-SQL Examples W +#+OPTIONS: num:nil +#+HTML_HEAD: +#+HTML_HEAD: +#+OPTIONS: ^:nil + +* [[file:s-sql-examples.org][S-SQL Examples Home Page]] +| [[file:s-sql-a.org][A]]| [[file:s-sql-b.org][B]]| [[file:s-sql-c.org][C]]| [[file:s-sql-d.org][D]]| [[file:s-sql-e.org][E]]| [[file:s-sql-f.org][F]]| [[file:s-sql-g.org][G]]| [[file:s-sql-h.org][H]]| [[file:s-sql-i.org][I]]| [[file:s-sql-j.org][J]]| [[file:s-sql-k.org][K]]| [[file:s-sql-l.org][L]]| [[file:s-sql-m.org][M]]| [[file:s-sql-n.org][N]]| [[file:s-sql-o.org][O]]| [[file:s-sql-p.org][P]]| [[file:s-sql-r.org][R]]| [[file:s-sql-s.org][S]]| [[file:s-sql-t.org][T]]| [[file:s-sql-u.org][U]]| [[file:s-sql-v.org][V]]| [[file:s-sql-w.org][W]]| [[file:s-sql-special-characters.org][Special Characters]] | [[file:calling-postgresql-stored-functions.org][Calling Postgresql Stored Functions and Procedures]]| + +* When + :PROPERTIES: + :CUSTOM_ID: when + :END: +#+begin_src lisp + (let ((param-latitude nil) (param-longitude t)) + (query (:select 'id 'name + (when param-latitude '0) + (when param-longitude 'longitude) + :from 'countries + :where (:= 'id 20)))) + + ((20 "UK" NIL -2)) +#+end_src + +* Window + :PROPERTIES: + :CUSTOM_ID: window + :END: +As stated in the postgresql documentation: "When a query involves multiple window functions, it is possible to write out each one with a separate OVER clause, but this is duplicative and error-prone if the same windowing behavior is wanted for several functions. Instead, each windowing behavior can be named in a WINDOW clause and then referenced in OVER". http://www.postgresql.org/docs/9.1/static/tutorial-window.html. They are available in postmodern as of the 29 October 2013 additions to the git repository. +#+begin_src lisp + (query (:select (:over (:sum 'salary) 'w) + (:over (:avg 'salary) 'w) + :from 'empsalary :window + (:as 'w (:partition-by 'depname :order-by (:desc 'salary))))) +#+end_src + +* With + :PROPERTIES: + :CUSTOM_ID: with + :END: +With queries are often referred to as Common Table Expressions. They are used as ways to write auxiliary statements for use in a larger query. The Postgresql documentation covers them at http://www.postgresql.org/docs/current/queries-with.html +#+begin_src lisp + (query + (:with + (:as 'upd + (:parens + (:update 'employees + :set 'sales-count (:= 'sales-count 1) + :where (:= 'id + (:select 'sales-person + :from 'accounts + :where (:= 'name "Acme Corporation"))) + :returning '*))) + (:insert-into 'employees-log + (:select '* 'current-timestamp + :from + 'upd)))) +#+end_src + +* With-recursive + :PROPERTIES: + :CUSTOM_ID: with-recursive + :END: +With-recursive allows the with auxiliary statement to refer to itself. These queries match the following template: +#+begin_src text +WITH RECURSIVE [temp table] [column list] +AS ( [seed statement] +UNION ALL [recursive statement - effectively looping through the table] ) + +[outer query which specifies the fields to be kept in the final result and throws away the intermediate results] + +#+end_src +Testing with recursive. When working with recursive queries it is important to be sure that the recursive part of the query will eventually return no tuples, or else the query will loop indefinitely. Sometimes, using UNION instead of UNION ALL can accomplish this by discarding rows that duplicate previous output rows. However, often a cycle does not involve output rows that are completely duplicate: it may be necessary to check just one or a few fields to see if the same point has been reached before. The standard method for handling such situations is to compute an array of the already-visited values. + +A few postmodern samples follow which match up with the [[https://www.postgresql.org/docs/current/queries-with.html][postgresql documentation examples:]] +#+begin_src lisp + (query + (:with-recursive + (:as (:t1 'n) + (:union-all (:values (:set 1)) + (:select (:+ 'n 1) + :from 't1 + :where (:< 'n 100)))) + (:select (:sum 'n) :from 't1)) + :single)) + + (query + (:with-recursive + (:as (:included-parts 'sub-part 'part 'quantity) + (:union-all + (:select 'sub-part 'part 'quantity + :from 'parts + :where (:= 'part "our-product")) + (:select 'p.sub-part 'p.part 'p.quantity + :from (:as 'included-parts 'pr) + (:as 'parts 'p) + :where (:= 'p.part 'pr.sub-part)))) + (:select 'sub-part (:as (:sum 'quantity) 'total-quantity) + :from 'included-parts + :group-by 'sub-part))) + + + (query + (:with-recursive + (:as (:search-graph 'id 'link 'data 'depth) + (:union-all + (:select 'g.id 'g.link 'g.data 1 + :from (:as 'graph 'g)) + (:select 'g.id 'g.link 'g.data (:= 'sg.depth 1) + :from (:as 'graph 'g) (:as 'search-graph 'sg) + :where (:= 'g.id 'sg.link)))) + (:select '* :from 'search-graph))) + + (query + (:with-recursive + (:as (:search-graph 'id 'link 'data'depth 'path 'cycle) + (:union-all + (:select 'g.id 'g.link 'g.data 1 + (:[] 'g.f1 'g.f2) nil + :from (:as 'graph 'g)) + (:select 'g.id 'g.link 'g.data (:= 'sg.depth 1) + (:|| 'path (:row 'g.f1 'g.f2)) + (:= (:row 'g.f1 'g.f2) + (:any* 'path)) + :from (:as 'graph 'g) + (:as 'search-graph 'sg) + :where (:and (:= 'g.id 'sg.link) + (:not 'cycle))))) + (:select '* :from 'search-graph))) + +#+end_src + +As a different example, consider a quicklisp dependency table where the fields are 'depends_on' and 'depended_on'. In other words library staple depends-on alexandria. So one record has "staple" in the depends_on column and "alexandria" in the depended_on column. + +A function to return a list of all the dependencies of a quicklisp library (assuming the data is in a table called "dependencies") could look like this: +#+begin_src lisp +(defun list-dependencies (lib-name) + "Returns a list of the names of the direct and indirect libraries depended-on by lib-name." + (sort (alexandria:flatten + (postmodern:query + (:with-recursive + (:as 'children + (:union + (:select 'depended-on + :from 'dependencies + :where (:= 'depends-on '$1)) + (:select 'a.depended-on + :from (:as 'dependencies 'a) + :inner-join (:as 'children 'b) + :on (:= 'a.depends-on 'b.depended-on)))) + (:select '* :from 'children)) + lib-name)) + #'string<))) +#+end_src diff --git a/doc/s-sql.html b/doc/s-sql.html index 9812b58..e3c89a4 100644 --- a/doc/s-sql.html +++ b/doc/s-sql.html @@ -1,7 +1,7 @@ - + S-SQL Reference Manual @@ -193,27 +193,38 @@ - + + -
    @@ -261,8 +272,9 @@

    Table of Contents

  • Defined Operators
  • Table Functions @@ -799,8 +811,10 @@

    SQL Types

    Numeric and decimal are variable storage size numbers with user specified precision. Up to 131072 digits before the decimal point; up to 16383 digits after the decimal point. -The syntax is numeric(precision, scale). Numeric columns with a specified scale will coerce input -values to that scale. For more detail, see https://www.postgresql.org/docs/current/datatype-numeric.html +

    + +

    +The syntax is numeric(precision, scale). Numeric columns with a specified scale will coerce input values to that scale. For more detail, see https://www.postgresql.org/docs/current/datatype-numeric.html

  • @@ -1095,7 +1109,7 @@

    Defined Operators

    -

    sql-op :+, :*, :%, :&, :|, :||, :and, :or, :=, :/, :!=, :<, :>, :<=, :>=, :^, :union, :union-all, :intersect, :intersect-all, :except, :except-all (&rest args)

    +

    sql-op :+, :*, :%, :&, :|, :||, :and, :or, :=, :/, :!=, :<, :>, :<=, :>=, :^, :union, :union-all, :call, :intersect, :intersect-all, :except, :except-all (&rest args)

    These are expanded as infix operators. When meaningful, they allow more than @@ -1109,6 +1123,23 @@

    sql-op :+, :*, :%, :&, :|, :||, :and, :or, :=, :/, :!=, handles the empty keyword symbol (written :||) specially, and treats it like :\|\|, so that it can be written without escapes. With :\|, this doesn't work.

    + +

    +We also have registered operators for Postgis, hstore and cube operations. See the following registration examples from the source code which might be useful if you need operators for other extensions: +

    +
    +
      ;; PostGIS operators
    +(register-sql-operators :2+-ary :&& :&< :|&<\|| :&> :<< :|<<\|| :>> :|@| :|\|&>|
    +                        :|\|>>| :~= :|@>| :|@<|)
    +
    +;; hstore operators
    +(register-sql-operators :2+-ary :-> :=> :? :?& :?\| :|<@| :|#=| :unary :%% :%#)
    +
    +;; cube operators
    +(register-sql-operators :2+-ary :&& :|@>| :|<@| :-> :~> :<-> :<#> :<=>)
    +
    +
    +

    @@ -1138,6 +1169,25 @@

    sql-op :or

    +
    +

    sql-op :call

    +
    +

    +:Call calls a Postgresql procedure. Remember that Postgresql procedures are not called within a select statement. The procedure name must be quoted or be a variable with a value of a quoted procedure name. Assuming a procedure named set_x_procedure1 exists, an example of calling it with parameters would be: +

    +
    +
    (query (:call 'set_x_procedure1 1 13))
    +
    +(let ((a 1) (b 2) (p 'my-proc))
    +  (query (:call p a b 3)))
    +
    +
    +

    +For more discussion, see Calling Postgresql Stored Functions and Procedures. +

    +
    +
    +

    sql-op :intersect

    @@ -1706,7 +1756,7 @@

    sql-op :in (value set)

    IMPORTANT REGARDING PARAMETERIZED QUERIES: For Postmodern versions before 1.33.7, you cannot use a list in a parameterized statement. You have to convert the list to a vector and use :any* rather than :in. See S-SQL#sql-op-any for more details.

    -
    (pomo:query (:select 'name :from 'employee :where (:= 'id (:any* '$1)))
    +
    (query (:select 'name :from 'employee :where (:= 'id (:any* '$1)))
                 #(1 3) :column)
      '("Jason" "Celia")
     
    @@ -1715,7 +1765,7 @@

    sql-op :in (value set)

    ;; Beginning with Postmodern version 1.33.7 you can also use lists

    -
    (pomo:query (:select 'name :from 'employee :where (:= 'id (:any* '$1)))
    +
    (query (:select 'name :from 'employee :where (:= 'id (:any* '$1)))
                 '(1 3) :column)
      '("Jason" "Celia")
     
    @@ -2778,9 +2828,9 @@

    sql-op :var-samp (&rest args)

    -
    -

    sql-op :range-between (&rest args)

    -
    +
    +

    sql-op :range-between (&rest args)

    +

    Range-between allows window functions to apply to different segments of a result set. It accepts the following keywords: :order-by, :rows-between, :range-between, @@ -2808,9 +2858,9 @@

    sql-op :range-between (&rest args)

    -
    -

    sql-op :rows-between (&rest args)

    -
    +
    +

    sql-op :rows-between (&rest args)

    +

    Rows-between allows window functions to apply to different segments of a result set. It accepts the following keywords: @@ -3011,9 +3061,9 @@

    sql-op :with-recursive (&rest args)

    -
    -

    sql-op :with-ordinality, :with-ordinality-as

    -
    +
    +

    sql-op :with-ordinality, :with-ordinality-as

    +

    Selects can use :with-ordinality or :with-ordinality-as parameters. Postgresql will give the new ordinality column the name of ordinality. :with-ordinality-as allows you to set different names for the columns in the result set.

    @@ -3696,19 +3746,60 @@

    sql-op :create-index (name &rest args)

    Create an index on a table. After the name of the index the keyword :on should follow, with the table name after it. Then the keyword :fields, followed by -one or more column names. Optionally, a :where clause with a condition can -be added at the end to make a partial index. +one or more column names. Other optional parameters are :using (to use index methods other than b-tree) :with (for storage parameters) or :where (for a condition can +be added at the end to make a partial index). See S-SQL-C for more examples.

    -
    (sql (:create-index 'gin-idx :on "historical-events" :using gin :fields 'data))
    +
    (query (:create-index 'films_idx :on 'films :fields 'title))
    +
    +(query (:create-index 'films-idx :on "films" :fields 'title 'id))
     
    -"CREATE INDEX gin_idx ON historical_events USING GIN (data)"
    +(query (:create-index 'gin-idx :on "historical-events" :using 'gin :fields 'data))
    +
    +
    +

    +Expressions can be used in the :fields specification: +

    +
    +
    (query (:create-index 'films_idx :on "films" :fields (:lower 'title)))
    +
    +
    +

    +Opclasses can be used within the fields specification: +

    +
    +
    (query (:create-index 'pointloc2 :on 'points :using 'gist
    +        :fields (:asc (:box 'location 'location)) (:nulls-last 'name)))
    +
    +
    +

    +Storage parameters can be set using a :with clause: +

    +
    +
    (query (:create-index 'gin-idx :on 'documents-table :using gin
    +        :fields 'locations :with (:= 'deduplicate-items off) (:= 'fillfactor 70)))
    +
    +
    +

    +Partial indexes can be set using a :where clause: +

    +
    +
    (query (:create-index 'orders_unbilled_idx :on 'orders :fields 'order-nr
    +        :where (:and (:is-not-true 'billed)
    +                            (:< 'order_nr 1000)))))
    +
    +
    +

    +Indexing a jsonb column named metadata: +

    +
    +
    (query (:create-index 'items-idx :on 'test-items :using 'gin
    +        :fields (:jsonb-path-ops 'metadata)))
     
    -

    sql-op :create-unique-index (name &rest args)

    @@ -4086,8 +4177,8 @@

    Programmer Built Queries

      -
    • Select Statements
      -
      +
    • Select Statements
      +

      Consider the following two toy examples where we determine the table and columns to be selected using symbols (either keyword or quoted) inside variables. @@ -4111,8 +4202,8 @@

      Programmer Built Queries

    • -
    • Update Statements
      -
      +
    • Update Statements
      +

      This works with update statements as well

      @@ -4125,8 +4216,8 @@

      Programmer Built Queries

    -
  • Insert Statements
    -
    +
  • Insert Statements
    +

    This works with insert-into statements as well

    @@ -4147,8 +4238,8 @@

    Programmer Built Queries

  • -
  • Delete Statements
    -
    +
  • Delete Statements
    +

    This works with delete statements as well

    @@ -4357,4 +4448,4 @@

    Queries with User Input

  • - + \ No newline at end of file diff --git a/doc/s-sql.org b/doc/s-sql.org index e75ec02..08eb71b 100644 --- a/doc/s-sql.org +++ b/doc/s-sql.org @@ -233,8 +233,8 @@ table (yes, I know this table is duplicated on other pages) shows the correspond Numeric and decimal are variable storage size numbers with user specified precision. Up to 131072 digits before the decimal point; up to 16383 digits after the decimal point. -The syntax is numeric(precision, scale). Numeric columns with a specified scale will coerce input -values to that scale. For more detail, see https://www.postgresql.org/docs/current/datatype-numeric.html + +The syntax is numeric(precision, scale). Numeric columns with a specified scale will coerce input values to that scale. For more detail, see https://www.postgresql.org/docs/current/datatype-numeric.html ** type db-null :PROPERTIES: @@ -463,7 +463,7 @@ Here is a somewhat contrived example using a countries and regions table. We wan :END: The following operators are defined: -** sql-op :+, :*, :%, :&, :|, :||, :and, :or, :=, :/, :!=, :<, :>, :<=, :>=, :^, :union, :union-all, :intersect, :intersect-all, :except, :except-all (&rest args) +** sql-op :+, :*, :%, :&, :|, :||, :and, :or, :=, :/, :!=, :<, :>, :<=, :>=, :^, :union, :union-all, :call, :intersect, :intersect-all, :except, :except-all (&rest args) :PROPERTIES: :CUSTOM_ID: sql-op-misc :END: @@ -476,6 +476,20 @@ should be queries (:select forms). Note that you'll have to escape pipe characters to enter them as keywords. S-SQL handles the empty keyword symbol (written :||) specially, and treats it like :\|\|, so that it can be written without escapes. With :\|, this doesn't work. + +We also have registered operators for Postgis, hstore and cube operations. See the following registration examples from the source code which might be useful if you need operators for other extensions: +#+begin_src lisp + ;; PostGIS operators +(register-sql-operators :2+-ary :&& :&< :|&<\|| :&> :<< :|<<\|| :>> :|@| :|\|&>| + :|\|>>| :~= :|@>| :|@<|) + +;; hstore operators +(register-sql-operators :2+-ary :-> :=> :? :?& :?\| :|<@| :|#=| :unary :%% :%#) + +;; cube operators +(register-sql-operators :2+-ary :&& :|@>| :|<@| :-> :~> :<-> :<#> :<=>) + +#+end_src ** sql-op :or :PROPERTIES: :CUSTOM_ID: sql-op-or @@ -498,6 +512,19 @@ or using parameterized queries (:= 'regions.id 'countries.region-id))) "North America" "Central America") #+END_SRC +** sql-op :call + :PROPERTIES: + :CUSTOM_ID: sql-op-call + :END: +:Call calls a Postgresql procedure. Remember that Postgresql procedures are not called within a select statement. The procedure name must be quoted or be a variable with a value of a quoted procedure name. Assuming a procedure named set_x_procedure1 exists, an example of calling it with parameters would be: +#+BEGIN_SRC lisp + (query (:call 'set_x_procedure1 1 13)) + + (let ((a 1) (b 2) (p 'my-proc)) + (query (:call p a b 3))) +#+END_SRC +For more discussion, see [[file:calling-postgresql-stored-functions.org][Calling Postgresql Stored Functions and Procedures]]. + ** sql-op :intersect :PROPERTIES: :CUSTOM_ID: sql-op-intersect @@ -2508,15 +2535,41 @@ Example calls would be: Create an index on a table. After the name of the index the keyword :on should follow, with the table name after it. Then the keyword :fields, followed by -one or more column names. Optionally, a :where clause with a condition can -be added at the end to make a partial index. +one or more column names. Other optional parameters are :using (to use index methods other than b-tree) :with (for storage parameters) or :where (for a condition can +be added at the end to make a partial index). See [[file:s-sql-c.org][S-SQL-C]] for more examples. #+BEGIN_SRC lisp -(sql (:create-index 'gin-idx :on "historical-events" :using gin :fields 'data)) + (query (:create-index 'films_idx :on 'films :fields 'title)) -"CREATE INDEX gin_idx ON historical_events USING GIN (data)" -#+END_SRC + (query (:create-index 'films-idx :on "films" :fields 'title 'id)) + (query (:create-index 'gin-idx :on "historical-events" :using 'gin :fields 'data)) +#+END_SRC +Expressions can be used in the :fields specification: +#+begin_src lisp + (query (:create-index 'films_idx :on "films" :fields (:lower 'title))) +#+end_src +Opclasses can be used within the fields specification: +#+begin_src lisp + (query (:create-index 'pointloc2 :on 'points :using 'gist + :fields (:asc (:box 'location 'location)) (:nulls-last 'name))) +#+end_src +Storage parameters can be set using a :with clause: +#+begin_src lisp + (query (:create-index 'gin-idx :on 'documents-table :using gin + :fields 'locations :with (:= 'deduplicate-items off) (:= 'fillfactor 70))) +#+end_src +Partial indexes can be set using a :where clause: +#+begin_src lisp + (query (:create-index 'orders_unbilled_idx :on 'orders :fields 'order-nr + :where (:and (:is-not-true 'billed) + (:< 'order_nr 1000))))) +#+end_src +Indexing a jsonb column named metadata: +#+begin_src lisp + (query (:create-index 'items-idx :on 'test-items :using 'gin + :fields (:jsonb-path-ops 'metadata))) +#+end_src ** sql-op :create-unique-index (name &rest args) :PROPERTIES: diff --git a/postmodern/package.lisp b/postmodern/package.lisp index d184c88..0e12d7b 100644 --- a/postmodern/package.lisp +++ b/postmodern/package.lisp @@ -100,6 +100,8 @@ ;; Reduced S-SQL interface #:sql #:sql-compile #:smallint #:bigint #:numeric #:real #:double-precision + #:timestamp-with-time-zone + #:timestamp-without-time-zone #:serial #:serial8 #:bytea #:text #:varchar #:*escape-sql-names-p* diff --git a/s-sql.asd b/s-sql.asd index b079036..be74df0 100644 --- a/s-sql.asd +++ b/s-sql.asd @@ -27,7 +27,8 @@ (:file "tests") (:file "test-arrays" :depends-on ("tests")) (:file "test-intervals" :depends-on ("tests")) - (:file "test-tables" :depends-on ("tests"))))) + (:file "test-tables" :depends-on ("tests")) + (:file "test-create-index" :depends-on ("tests"))))) :perform (test-op (o c) (uiop:symbol-call :s-sql-tests '#:prompt-connection) (uiop:symbol-call :fiveam '#:run! :s-sql))) diff --git a/s-sql/package.lisp b/s-sql/package.lisp index 864d340..ae72873 100644 --- a/s-sql/package.lisp +++ b/s-sql/package.lisp @@ -7,9 +7,14 @@ #:numeric #:real #:double-precision + #:double-precision[] #:bytea #:text #:varchar + #:serial + #:serial8 + #:timestamp-with-time-zone + #:timestamp-without-time-zone #:db-null #:sql-type-name #:*standard-sql-strings* diff --git a/s-sql/s-sql.lisp b/s-sql/s-sql.lisp index c130b50..a91da32 100644 --- a/s-sql/s-sql.lisp +++ b/s-sql/s-sql.lisp @@ -82,6 +82,15 @@ must appear in the order defined." words)) ,@body))) +(defun h-to-u (str) +; (to-sql-name str nil t) + (cond ((symbolp str) + (remove #\' + (string-downcase (substitute #\_ #\- (symbol-name str) :test #'char=)))) + ((stringp str) + (remove #\' (substitute #\_ #\- str :test #'char=))) + (t (remove #\' (format nil "~a" str))))) + (defgeneric to-s-sql-string (arg) (:documentation "Convert a Lisp value to its textual unescaped SQL representation. Returns a second value indicating whether this value should be @@ -100,24 +109,24 @@ You can define to-s-sql-string methods for your own datatypes.") (with-output-to-string (out) (write-char #\{ out) (loop :for sep := "" :then #\, :for x :across arg :do - (princ sep out) - (multiple-value-bind (string escape) (to-s-sql-string x) - (if escape (cl-postgres::write-quoted string out) - (write-string string out)))) + (princ sep out) + (multiple-value-bind (string escape) (to-s-sql-string x) + (if escape (cl-postgres::write-quoted string out) + (write-string string out)))) (write-char #\} out)) t))) (:method ((arg cons)) ;lists, but not nil (if (alexandria:proper-list-p arg) (values - (with-output-to-string (out) - (write-char #\( out) - (loop :for sep := "" :then #\, :for x :in arg :do - (princ sep out) - (multiple-value-bind (string escape) (to-s-sql-string x) - (if escape (cl-postgres::write-quoted string out) - (cl-postgres::write-string string out)))) - (write-char #\) out)) - nil) + (with-output-to-string (out) + (write-char #\( out) + (loop :for sep := "" :then #\, :for x :in arg :do + (princ sep out) + (multiple-value-bind (string escape) (to-s-sql-string x) + (if escape (cl-postgres::write-quoted string out) + (cl-postgres::write-string string out)))) + (write-char #\) out)) + nil) (error "Value ~S can not be converted to an SQL literal." arg))) (:method ((arg array)) (values @@ -128,15 +137,15 @@ You can define to-s-sql-string methods for your own datatypes.") (let ((factor (reduce #'* (cdr dims)))) (loop :for i :below (car dims) :for sep := "" :then #\, :do - (princ sep out) - (recur (cdr dims) (+ off (* factor i))))) + (princ sep out) + (recur (cdr dims) (+ off (* factor i))))) (loop :for sep := "" :then #\, :for i :from off :below (+ off (car dims)) :do - (princ sep out) - (multiple-value-bind (string escape) - (to-s-sql-string (row-major-aref arg i)) - (if escape (cl-postgres::write-quoted string out) - (write-string string out))))) + (princ sep out) + (multiple-value-bind (string escape) + (to-s-sql-string (row-major-aref arg i)) + (if escape (cl-postgres::write-quoted string out) + (write-string string out))))) (write-char #\} out))) (recur (array-dimensions arg) 0))) t)) @@ -250,12 +259,14 @@ hyphens." '(array (unsigned-byte 8))) (deftype text () 'string) +(deftype timestamp-with-time-zone () + 'timestamp) (deftype varchar (length) (declare (ignore length)) `string) (deftype serial () 'integer) (deftype serial8 () 'integer) - +(deftype tsvector () 'tsvector) (deftype db-null () "Type for representing NULL values. Use like (or integer db-null) for declaring a type to be an integer that may be null." @@ -266,11 +277,13 @@ for declaring a type to be an integer that may be null." (defgeneric sql-type-name (lisp-type &rest args) (:documentation "Transform a lisp type into a string containing something -SQL understands. Default is to just use the type symbol's name.") +SQL understands. Default is to just use the type symbol's name. This method is indirectly used in :as, :type, :function, :expand-table-column, :alter-table-column and :create-domain. These are further indirectly often used by :select and :create-table operators.") (:method ((lisp-type symbol) &rest args) - (cond ((and args (equal (symbol-name lisp-type) "GEOMETRY")) ; geometry type from postgis - (format nil "geometry (~{~a~^, ~})" args)) - (t (substitute #\Space #\- (symbol-name lisp-type) :test #'char=)))) + ;; This should pick up custom types + (cond ((and args (symbol-name lisp-type)) + (format nil "~a(~{~a~^, ~})" (sql-type-name lisp-type) args)) + (t + (substitute #\_ #\- (symbol-name lisp-type) :test #'char=)))) (:method ((lisp-type (eql 'string)) &rest args) (cond (args (format nil "CHAR(~A)" (car args))) (t "TEXT"))) @@ -292,12 +305,25 @@ SQL understands. Default is to just use the type symbol's name.") (:method ((lisp-type (eql 'double-precision)) &rest args) (declare (ignore args)) "DOUBLE PRECISION") + (:method ((lisp-type (eql 'double-precision[])) &rest args) + (declare (ignore args)) + "DOUBLE PRECISION[]") + (:method ((lisp-type (eql 'timestamp-with-time-zone)) &rest args) + (declare (ignore args)) + "TIMESTAMP WITH TIME ZONE") + (:method ((lisp-type (eql 'timestamp-without-time-zone)) &rest args) + (declare (ignore args)) + "TIMESTAMP WITHOUT TIME ZONE") (:method ((lisp-type (eql 'serial)) &rest args) (declare (ignore args)) "SERIAL") (:method ((lisp-type (eql 'serial8)) &rest args) (declare (ignore args)) "SERIAL8") + (:method ((lisp-type (eql 'pgvector)) &rest args) + (cond (args + (format nil "vector(~{~a~^, ~})" args)) + (t "vector()"))) (:method ((lisp-type (eql 'array)) &rest args) (format nil "~a[]" (to-type-name (car args)))) (:method ((lisp-type (eql 'db-null)) &rest args) @@ -377,8 +403,8 @@ Symbols will be converted to SQL names. Examples: "Compile-time expansion of forms into lists of stuff that evaluate to strings (which will form a SQL query when concatenated). :default will return ' DEFAULT' " - - (cond ((eq arg :default) (list " DEFAULT ")) ((and (consp arg) (keywordp (first arg))) + (cond ((eq arg :default) (list " DEFAULT ")) + ((and (consp arg) (keywordp (first arg))) (expand-sql-op (car arg) (cdr arg))) ((and (consp arg) (eq (first arg) 'quote)) (list (sql-escape (second arg)))) @@ -608,6 +634,27 @@ return. E.g: ((21 \"US-North America\"))" `("(" ,@(sql-expand-list args " || ") ")")) +(def-sql-op :text-pattern-ops (arg) + `(,@(sql-expand arg) " text_pattern_ops")) + +(def-sql-op :jsonb-path-ops (arg) + `(,@(sql-expand arg) " jsonb_path_ops")) + +(def-sql-op :jsonb-ops (arg) + `(,@(sql-expand arg) " jsonb_ops")) + +(def-sql-op :array-ops (arg) + `(,@(sql-expand arg) " array_ops")) + +(def-sql-op :gin-trgm-ops (arg) + `(,@(sql-expand arg) " gin_trgm_ops")) + +(def-sql-op :to-tsvector (&rest args) + `("to_tsvector (" ,@(sql-expand-list args) ")")) + +(def-sql-op :to-tsquery (&rest args) + `("to_tsquery (" ,@(sql-expand-list args) ")")) + (def-sql-op :asc (arg) `(,@(sql-expand arg) " ASC")) @@ -620,6 +667,12 @@ return. E.g: (def-sql-op :nulls-last (arg) `(,@(sql-expand arg) " NULLS LAST")) +(def-sql-op :nulls-distinct (arg) + `(,@(sql-expand arg) " NULLS DISTINCT")) + +(def-sql-op :nulls-not-distinct (arg) + `(,@(sql-expand arg) " NULLS NOT DISTINCT")) + (def-sql-op :as (form name &rest fields) `(,@(sql-expand form) " AS " ,@(sql-expand name) ,@(when fields @@ -682,6 +735,10 @@ only applies to seconds." `("INTERVAL " ,@(sql-expand arg) "(" ,@(sql-expand precision) ")") `("INTERVAL " ,@(sql-expand arg)))) +(def-sql-op :call (proc &rest args) + "Call takes the name of a postgresql procedure (NOTE: Not postgresql function) and the arguments to be passed to that procedure. The procedure name must be quoted or be a variable with a value of a quoted procedure name." + `("CALL " ,@ (sql-expand proc) "(" ,@(sql-expand-list args) ")")) + (def-sql-op :current-date () "Provides the current time. The default is universal time. If you want a more human readable approach, you can use :to-char. As an example: @@ -809,6 +866,9 @@ e.g. (make-interval (\"days\" 10)(\"hours\" 4))." (def-sql-op :is-true (arg) `("(" ,@(sql-expand arg) " IS TRUE)")) +(def-sql-op :is-not-true (arg) + `("(" ,@(sql-expand arg) " IS NOT TRUE)")) + (def-sql-op :is-false (arg) `("(" ,@(sql-expand arg) " IS FALSE)")) @@ -834,16 +894,6 @@ e.g. (make-interval (\"days\" 10)(\"hours\" 4))." ,@(when order-by `(" ORDER BY " ,@(sql-expand-list order-by) ")")) ")"))) -(define-condition malformed-composite-type-error (error) - ((text :initarg :text :reader text))) - -(defun cons-to-sql-name-strings (item) - "Takes a list of two items and returns a single string separated by a space. -The items will be converted to sql compatible namestrings." - (if (= 2 (length item)) - (implode " " (mapcar #'to-sql-name item)) - (error 'malformed-composite-type-error :text item))) - (def-sql-op :count (&rest args) "Count returns the number of rows. It can be the number of rows collected by the select statement as in: @@ -1916,6 +1966,12 @@ one of which is ~s." type 'db-null)) (values type nil))) +(defun expand-timestamp (timestamp-symbol) + "Write out timestamps" + (case timestamp-symbol + (timestamp-without-time-zone '("TIMESTAMP WITHOUT TIME ZONE")) + (timestamp-with-time-zone '("TIMESTAMP WITH TIME ZONE")))) + (defun expand-interval (option) "Provide interval limit options" (case option @@ -2093,7 +2149,8 @@ definition." '(" GENERATED ALWAYS AS IDENTITY ")) (:generated-always (when value - `(" GENERATED ALWAYS AS (" ,@(sql-expand-names value) ") STORED"))) + `(" GENERATED ALWAYS AS (" + ,@(sql-expand value) ") STORED"))) (:primary-key (cond ((and value (stringp value)) `(" PRIMARY KEY " ,value)) ((and value (keywordp value)) @@ -2167,6 +2224,20 @@ would be redundant." (t (sql-error "Unknown table option: ~A" name)))))) (t (sql-error "Unknown table option: ~A" name)))) +(define-condition malformed-composite-type-error (error) + ((text :initarg :text :reader text))) + +(defun create-composite-col-type-strings (item) + "Takes a list of two items and returns a single string separated by a space. +The items will be converted to sql compatible namestrings." + (if (> (length item) 1) + (implode " " (loop for x in item + for counter from 1 + collect + (if (= 1 counter) + (to-sql-name x) + (to-type-name x)))) + (error 'malformed-composite-type-error :text item))) (def-sql-op :create-composite-type (type-name &rest args) "Creates a composite type with a type-name and two or more @@ -2186,7 +2257,7 @@ columns. Sample call would be: " AS (" ,(implode ", " (loop for x in args - collect (cons-to-sql-name-strings x))) + collect (create-composite-col-type-strings x))) ")")) (def-sql-op :create-table (name (&rest columns) &rest options) @@ -2351,14 +2422,22 @@ have tables without columns that are inherited or partitioned." (:owned-by `(" OWNED BY " ,(to-sql-name argument))) (t (sql-error "Unknown ALTER SEQUENCE action ~A" action))))) +(defun expand-field-names (names &optional (sep ", ")) + (loop :for (name . rest) :on names + :if (consp name) + :append (sql-expand name) + :else + :collect (h-to-u name) + :if rest :collect sep)) + (defun expand-create-index (name args) "Available parameters - in order after name - are :concurrently, :on, :using, - :fields and :where.The advantage to using the keyword :concurrently is that + :fields, :with and :where.The advantage to using the keyword :concurrently is that writes to the table from other sessions are not locked out while the index is is built. The disadvantage is that the table will need to be scanned twice. Everything is a trade-off." (split-on-keywords ((unique ? -) (concurrently ? -) (on) (using ?) (fields *) - (where ?)) + (with * ?) (where ?)) args `(,@(when unique '("UNIQUE ")) "INDEX " @@ -2378,7 +2457,9 @@ Everything is a trade-off." ((consp (car using)) (to-sql-name (cadar using))) (t (to-sql-name (car using)))))) - " (" ,@(sql-expand-names fields) ")" + " (" ,@(expand-field-names fields) ")" + ,@(when with + `(" WITH " ,@(sql-expand-list with))) ,@(when where `(" WHERE " ,@(sql-expand (first where))))))) (def-sql-op :create-index (name &rest args) diff --git a/s-sql/tests/test-create-index.lisp b/s-sql/tests/test-create-index.lisp new file mode 100644 index 0000000..2f84269 --- /dev/null +++ b/s-sql/tests/test-create-index.lisp @@ -0,0 +1,222 @@ +;;;; -*- Mode: LISP; Syntax: Ansi-Common-Lisp; Base: 10; Package: S-SQL-TESTS; -*- +(in-package :s-sql-tests) + +(def-suite :s-sql-create-index + :description "Create Index suite for s-sql" + :in :s-sql) + +(in-suite :s-sql-create-index) + + +;;; TESTS ON INDEX FIELDS +(test create-index-1 + "Testing create-index. Available parameters - in order after name - +are :concurrently, :on, :using, :fields and :where.The advantage to using the +keyword :concurrently is that writes to the table +from other sessions are not locked out while the index is is built. The disadvantage is +that the table will need to be scanned twice. Everything is a trade-off." + (is (equal (sql (:create-index 'films_idx :on 'films :fields 'title)) + "CREATE INDEX films_idx ON films (title)")) + + (is (equal (sql (:create-index 'films_idx :on "films" :using gin :fields 'title)) + "CREATE INDEX films_idx ON films USING gin (title)")) + (is (equal (sql (:create-index 'doc-tags-id-tags + :on "doc-tags-array" :using gin :fields 'tags)) + "CREATE INDEX doc_tags_id_tags ON doc_tags_array USING gin (tags)")) + (is (equal (sql (:create-index 'title-index :unique :on 'films :fields 'title + :with (:= 'fillfactor 70))) + "CREATE UNIQUE INDEX title_index ON films (title) WITH (fillfactor = 70)")) + (is (equal (sql (:create-unique-index 'doc-tags-id-doc-id + :on "doc-tags-array" :fields 'doc-id)) + "CREATE UNIQUE INDEX doc_tags_id_doc_id ON doc_tags_array (doc_id)")) + (is (equal (sql (:create-index 'films-idx :concurrently + :on "films" :using 'btree :fields 'created-at)) + "CREATE INDEX CONCURRENTLY films_idx ON films USING btree (created_at)")) + (is (equal (sql (:create-index 'films-idx :unique :concurrently :on "films" + :using 'btree :fields 'created-at)) + "CREATE UNIQUE INDEX CONCURRENTLY films_idx ON films USING btree (created_at)")) + (is (equal (sql (:create-index (:if-not-exists 'test-uniq-1-idx) + :on test-uniq :fields 'name)) + "CREATE INDEX IF NOT EXISTS test_uniq_1_idx ON test_uniq (name)")) + +;;; where clause tests for partial indexes + (is (equal (sql (:create-index 'orders_unbilled_idx :on 'orders :fields order-nr + :where (:and (:is-not-true 'billed) + (:< 'order_nr 1000)))) + "CREATE INDEX orders_unbilled_idx ON orders (order_nr) WHERE ((billed IS NOT TRUE) and (order_nr < 1000))")) + (with-test-connection + (query (:drop-table :if-exists 'george :cascade)) + (is (eq (table-exists-p 'george) nil)) + (query (:create-table 'george ((id :type integer)))) + (is (eq (table-exists-p 'george) t)) + (query (:create-index 'george-idx :on 'george :fields 'id)) + (is (pomo:index-exists-p 'george-idx)) + (is (pomo:index-exists-p "george-idx")) + (query (:drop-table :if-exists 'george :cascade)) + (is (not (pomo:index-exists-p 'george-idx))) + + (query (:drop-table :if-exists 'access-log :cascade)) + (query (:create-table 'access-log ((url :type varchar) (client-ip :type inet)))) + (query (:create-index 'access-log-client-ip-idx :on 'access-log :fields 'client-ip + :where (:not (:and (:> 'client-ip "192.168.100.0") + (:< 'client-ip "192.168.100.255"))))) + (is (pomo:index-exists-p 'access-log-client-ip-idx)) + (query (:drop-table :if-exists 'access-log :cascade)))) + +(test create-index-fields-1 + (is (equal + (sql (:create-index 'films-idx :on "films" :fields 'title)) + "CREATE INDEX films_idx ON films (title)")) + (is (equal + (sql (:create-index 'films-idx :on "films" :fields 'title 'id)) + "CREATE INDEX films_idx ON films (title, id)")) + ;; Now without quoting the fields + (is (equal + (sql (:create-index 'films-idx :on "films" :fields title id)) + "CREATE INDEX films_idx ON films (title, id)"))) + +(test create-index-fields-expressions + (is (equalp (sql (:create-index 'films_idx :on "films" :fields (:lower 'title))) + "CREATE INDEX films_idx ON films (lower(title))")) + (is (equalp (sql (:create-index 'films-idx :on 'films + :fields (:lower 'title) (:upper 'product-name))) + "CREATE INDEX films_idx ON films (lower(title), upper(product_name))")) + (is (equalp + (sql (:create-index 'films-idx :on 'films + :fields (:asc (:lower 'title)) (:nulls-last (:upper 'product-name)))) + "CREATE INDEX films_idx ON films (lower(title) ASC, upper(product_name) NULLS LAST)"))) + +(test create-index-fields-base-opclass + (is (equal + (sql (:create-index 'films-idx :on 'films :using gin + :fields (:nulls-first 'customer-id) (:asc 'order-date))) + "CREATE INDEX films_idx ON films USING gin (customer_id NULLS FIRST, order_date ASC)")) + (is (equal + (sql (:create-index 'films-idx :on 'films :using gin + :fields (:nulls-last 'customer-id) (:asc 'order-date))) + "CREATE INDEX films_idx ON films USING gin (customer_id NULLS LAST, order_date ASC)")) + (is (equal + (sql (:create-index 'films-idx :on 'films :using gin + :fields (:nulls-first 'customer-id) 'order-date)) + "CREATE INDEX films_idx ON films USING gin (customer_id NULLS FIRST, order_date)"))) + +(test create-index-fields-btree-opclass +;;; CREATE INDEX ON test USING btree ((data ->> 'field')); + (is (equal + (sql (:create-index 'test-idx :on 'test :using btree + :fields (:->> 'data "field"))) + "CREATE INDEX test_idx ON test USING btree ((data ->> E'field'))")) + (is (equal + (sql (:create-index 'users-idx :on 'users + :fields (:text-pattern-ops 'email))) + "CREATE INDEX users_idx ON users (email text_pattern_ops)"))) + +(test create-index-fields-gin-opclass + ;; Create index statements pulled from https://pganalyze.com/blog/gin-index + ;; CREATE INDEX ON test_items USING gin(metadata jsonb_path_ops); + (is (equal + (sql (:create-index 'items-idx :on 'test-items :using 'gin + :fields (:jsonb-path-ops 'metadata))) + "CREATE INDEX items_idx ON test_items USING gin (metadata jsonb_path_ops)")) +;;; CREATE INDEX trgm_idx ON test_trgm USING gin (t1 gin_trgm_ops); + (is (equal + (sql (:create-index 'trgm-idx :on 'test-trgm :using gin + :fields (:gin-trgm-ops 'tc1))) + "CREATE INDEX trgm_idx ON test_trgm USING gin (tc1 gin_trgm_ops)")) +;;; CREATE INDEX pgweb_idx ON pgweb USING GIN (to_tsvector('english', body)); + (is (equal + (sql (:create-index 'pgweb-idx :on 'pgweb :using gin + :fields (:to-tsvector "english" 'body))) + "CREATE INDEX pgweb_idx ON pgweb USING gin (to_tsvector (E'english', body))"))) + +(test create-index-fields-box-operators + (is (equal + (sql (:create-index 'pointloc1 :on 'points :using gist + :fields (:asc (:box 'location)))) + "CREATE INDEX pointloc1 ON points USING gist (box(location) ASC)")) + (is (equal + (sql (:create-index 'pointloc0 :on 'points :using gist + :fields (:box 'location 'location))) + "CREATE INDEX pointloc0 ON points USING gist (box(location, location))")) + + (is (equal (sql (:create-index 'pointloc1 :on 'points :using gist + :fields (:asc (:box 'location)) 'name)) + "CREATE INDEX pointloc1 ON points USING gist (box(location) ASC, name)")) + ;; https://www.postgresql.org/docs/current/sql-createindex.html + (is (equal + (sql (:create-index 'pointloc2 :on 'points :using gist + :fields (:asc (:box 'location 'location)) (:nulls-last 'name))) + "CREATE INDEX pointloc2 ON points USING gist (box(location, location) ASC, name NULLS LAST)")) + (is (equal + (sql (:create-index 'pointloc4 :on 'points :using gist + :fields (:asc (:box 'location 'location)) (:nulls-last 'name))) + "CREATE INDEX pointloc4 ON points USING gist (box(location, location) ASC, name NULLS LAST)")) + (is (equal + (sql (:create-index 'pointloc3 :on 'points :using gist + :fields 'name (:asc (:box 'location)))) + "CREATE INDEX pointloc3 ON points USING gist (name, box(location) ASC)"))) + +(test create-index-storage + ;; An additional difference between the first and second is field being quoted and not quoted + (is (equal + (sql (:create-index 'title-index :on 'films :fields 'title + :with (:= 'deduplicate-items 'off))) + "CREATE INDEX title_index ON films (title) WITH (deduplicate_items = \"off\")")) + (is (equal + (sql (:create-index 'title-index :on 'films :fields 'title + :with (:= 'fillfactor 70))) + "CREATE INDEX title_index ON films (title) WITH (fillfactor = 70)")) + (is (equal + (sql (:create-index 'gin-idx :on 'documents-table :using gin + :fields 'locations :with (:= 'fastupdate 'off))) + "CREATE INDEX gin_idx ON documents_table USING gin (locations) WITH (fastupdate = \"off\")")) + (is (equal (sql (:create-index 'gin-idx :on 'documents-table :using 'gin + :fields 'locations :with (:= 'fastupdate 'off) (:= 'fillfactor 70))) + "CREATE INDEX gin_idx ON documents_table USING gin (locations) WITH (fastupdate = \"off\"), (fillfactor = 70)")) + (is (equal (sql (:create-index 'gin-idx :on 'documents-table :using 'gin + :fields 'locations :with (:= 'deduplicate-items 'off))) + "CREATE INDEX gin_idx ON documents_table USING gin (locations) WITH (deduplicate_items = \"off\")"))) + +(test to-tsvector + (with-test-connection + (query (:drop-table :if-exists 't11 :cascade)) + (query (:create-table 't11 + ((title :type (or text db-null)) + (body :type (or text db-null)) + (tsv :type (or tsvector db-null) + :generated-always + (:to-tsvector "english" 'body))))) + (query (:create-index 'textsearch11-idx :on 't11 :using 'gin :fields 'tsv)) + (is (pomo:index-exists-p 'textsearch11-idx)) + (query (:drop-table 't11 :cascade)) + (query (:drop-table :if-exists 't12 :cascade)) + (query (:create-table 't12 + ((id :type bigint :primary-key :identity-by-default) + (body :type (or text db-null))))) + (query (:alter-table 't12 :add-column 'tsv :type (or tsvector db-null) + :generated-always + (:to-tsvector "english" 'body))) + (query (:create-index 'textsearch12-idx :on 't12 :using 'gin :fields 'tsv)) + (let ((quotes '(("Successful is the person who has lived well, laughed often and loved much, who has gained the respect of children, who leaves the world better than they found it, who has never lacked appreciation for the earth's beauty, who never fails to look for the best in others or give the best of themselves.") + ("Why should the way I feel depend on the thoughts in someone else's head?") + ("Finish each day and be done with it. You have done what you could. Some blunders and absurdities no doubt crept in; forget them as soon as you can. Tomorrow is a new day; begin it well and serenely and with too high a spirit to be encumbered with your old nonsense.") + ("Your actions speak so loud, I can't hear what you say.") + ("Hidden away in the inner nature of the real man is the law of his life, and someday he will discover it and consciously make use of it. He will heal himself, make himself happy and prosperous, and life in an entirely different world. For he will have discovered that life is from within and not from without.") + ("People only see what they are prepared to see. If you look for what is good and what you can be grateful for you will find it everywhere.") + ("Let me never fall into the vulgar mistake of dreaming that I am persecuted whenever I am contradicted.") + ("People do not seem to realize that their opinion of the world is also a confession of character.")))) + (query (:insert-rows-into 't12 :columns 'body :values quotes)) + (is (equal (query (:select 'id 'body :from 't12 + :where (:@@ (:to-tsvector "english" 'body) + (:to-tsquery "english" "spirit")))) + '((3 + "Finish each day and be done with it. You have done what you could. Some blunders and absurdities no doubt crept in; forget them as soon as you can. Tomorrow is a new day; begin it well and serenely and with too high a spirit to be encumbered with your old nonsense.")))) + (is (equal (query (:select 'id 'body :from 't12 + :where (:@@ (:to-tsvector 'body) + (:to-tsquery "spirit")))) + '((3 + "Finish each day and be done with it. You have done what you could. Some blunders and absurdities no doubt crept in; forget them as soon as you can. Tomorrow is a new day; begin it well and serenely and with too high a spirit to be encumbered with your old nonsense."))))) + (is (equal (query (:select 'id 'body :from 't12 :where (:@@ (:to-tsvector 'body) (:to-tsquery "depend | loud")))) + '((2 "Why should the way I feel depend on the thoughts in someone else's head?") + (4 "Your actions speak so loud, I can't hear what you say.")))) + (query (:drop-table :if-exists 't12 :cascade)))) diff --git a/s-sql/tests/test-tables.lisp b/s-sql/tests/test-tables.lisp index a96e217..86e0e2f 100644 --- a/s-sql/tests/test-tables.lisp +++ b/s-sql/tests/test-tables.lisp @@ -8,35 +8,53 @@ (in-suite :s-sql-tables) (test expand-table-column - "Testing expand-table-column" - (is (equal (s-sql::expand-table-column 'code '(:type varchar :primary-key t)) - '("code" " " "VARCHAR" " NOT NULL" " PRIMARY KEY "))) - (is (equal (s-sql::expand-table-column 'code '(:type (or char db-null) :primary-key t)) - '("code" " " "CHAR" " PRIMARY KEY "))) - (is (equal (s-sql::expand-table-column 'code '(:type (or (string 5) db-null) :primary-key t)) - '("code" " " "CHAR(5)" " PRIMARY KEY "))) - (is (equal (s-sql::expand-table-column 'code '(:type (or (varchar 64) db-null) - :collate "en_US.utf8")) - '("code" " " "VARCHAR(64)" " COLLATE \"" "en_US.utf8" "\""))) - (is (equal (s-sql::expand-table-column 'color '(:type int :generated-as-identity-always t)) - '("color" " " "INT" " NOT NULL" " GENERATED ALWAYS AS IDENTITY "))) - (is (equal (s-sql::expand-table-column 'color '(:type int :generated-as-identity-by-default t)) - '("color" " " "INT" " NOT NULL" " GENERATED BY DEFAULT AS IDENTITY "))) - (is (equal (s-sql::expand-table-column 'color '(:type int :identity-by-default t)) - '("color" " " "INT" " NOT NULL" " GENERATED BY DEFAULT AS IDENTITY "))) - (is (equal (s-sql::expand-table-column 'color '(:type int :identity-always t)) - '("color" " " "INT" " NOT NULL" " GENERATED ALWAYS AS IDENTITY "))) - (is (equal (s-sql::expand-table-column 'color '(:type int :generated-as-identity-always)) - '("color" " " "INT" " NOT NULL" " GENERATED ALWAYS AS IDENTITY "))) - (is (equal (s-sql::expand-table-column 'color '(:type int :generated-as-identity-by-default)) - '("color" " " "INT" " NOT NULL" " GENERATED BY DEFAULT AS IDENTITY "))) - (is (equal (s-sql::expand-table-column 'color '(:type int :identity-by-default)) - '("color" " " "INT" " NOT NULL" " GENERATED BY DEFAULT AS IDENTITY "))) - (is (equal (s-sql::expand-table-column 'color '(:type int :identity-always)) - '("color" " " "INT" " NOT NULL" " GENERATED ALWAYS AS IDENTITY "))) - (is (equal (s-sql::expand-table-column 'area '(:type (or real db-null) - :generated-always ((* w h)))) - '("area" " " "REAL" " GENERATED ALWAYS AS (" "(" "w" " * " "h" ")" ") STORED")))) + "Testing expand-table-column" + (is (equal (s-sql::expand-table-column 'code '(:type varchar :primary-key t)) + '("code" " " "VARCHAR" " NOT NULL" " PRIMARY KEY "))) + (is (equal (s-sql::expand-table-column 'code '(:type (or char db-null) + :primary-key t)) + '("code" " " "CHAR" " PRIMARY KEY "))) + (is (equal (s-sql::expand-table-column 'code '(:type (or (string 5) db-null) + :primary-key t)) + '("code" " " "CHAR(5)" " PRIMARY KEY "))) + (is (equal (s-sql::expand-table-column 'code '(:type (or (varchar 64) db-null) + :collate "en_US.utf8")) + '("code" " " "VARCHAR(64)" " COLLATE \"" "en_US.utf8" "\""))) + (is (equal (s-sql::expand-table-column 'color '(:type int + :generated-as-identity-always t)) + '("color" " " "INT" " NOT NULL" " GENERATED ALWAYS AS IDENTITY "))) + (is (equal (s-sql::expand-table-column 'color + '(:type int + :generated-as-identity-by-default t)) + '("color" " " "INT" " NOT NULL" " GENERATED BY DEFAULT AS IDENTITY "))) + (is (equal (s-sql::expand-table-column 'color '(:type int :identity-by-default t)) + '("color" " " "INT" " NOT NULL" " GENERATED BY DEFAULT AS IDENTITY "))) + (is (equal (s-sql::expand-table-column 'color '(:type int :identity-always t)) + '("color" " " "INT" " NOT NULL" " GENERATED ALWAYS AS IDENTITY "))) + (is (equal (s-sql::expand-table-column 'color + '(:type int :generated-as-identity-always)) + '("color" " " "INT" " NOT NULL" " GENERATED ALWAYS AS IDENTITY "))) + (is (equal (s-sql::expand-table-column 'color + '(:type int + :generated-as-identity-by-default)) + '("color" " " "INT" " NOT NULL" " GENERATED BY DEFAULT AS IDENTITY "))) + (is (equal (s-sql::expand-table-column 'color '(:type int :identity-by-default)) + '("color" " " "INT" " NOT NULL" " GENERATED BY DEFAULT AS IDENTITY "))) + (is (equal (s-sql::expand-table-column 'color '(:type int :identity-always)) + '("color" " " "INT" " NOT NULL" " GENERATED ALWAYS AS IDENTITY "))) + (is (equal (s-sql::expand-table-column 'area '(:type (or real db-null) + :generated-always (* w h))) + '("area" " " "REAL" " GENERATED ALWAYS AS (" (SQL-ESCAPE (* W H)) ") STORED"))) + (is (equal (s-sql::expand-table-column 'area '(:type (or real db-null) + :generated-always (* 'w 'h))) + '("area" " " "REAL" " GENERATED ALWAYS AS (" (SQL-ESCAPE (* 'W 'H)) ") STORED")))) + +(test expand-table-column-2 + (is (equal (s-sql::expand-table-column 'embedding '(:type (vector 3))) + '("embedding" " " "VECTOR(3)" " NOT NULL"))) + (is (equal (s-sql::expand-table-column 'embedding + '(:type timestamp-without-time-zone)) + '("embedding" " " "TIMESTAMP WITHOUT TIME ZONE" " NOT NULL")))) (test expand-table-names-1 "Testing expand-table-names basic" @@ -185,7 +203,10 @@ (is (equal (sql (:create-table (distributors-in-hell) ((did :type (or integer db-null))))) "CREATE TABLE distributors_in_hell (did INTEGER)")) - + (is (equal (sql (:create-table 'items + ((id :type bigserial :primary-key t) + (embedding :type (:vector 3))))) + "CREATE TABLE items (id BIGSERIAL NOT NULL PRIMARY KEY , embedding VECTOR(3) NOT NULL)")) ;; The difference with the first four tests are whether the tablename is a keyword, quoted, unquoted or a string ;; preference should be quoted, but your mileage may vary. (is (equal (sql (:create-table :films @@ -273,23 +294,27 @@ "CREATE TABLE distributors (did INTEGER, name VARCHAR(40), CONSTRAINT con1 CHECK ((did > 100) and (name <> E'')))")) ;; Define a primary key table constraint for the table films: - (is (equal (sql (:create-table 'films - ((code :type (or (string 5) db-null) :constraint 'firstkey :primary-key 't) - (title :type (varchar 40)) - (did :type integer) - (date-prod :type (or date db-null)) - (kind :type (or (varchar 10) db-null)) - (len :type (or interval db-null) :interval :hour-to-minute)) - (:constraint code-title :primary-key code title))) + (is (equal + (sql (:create-table 'films + ((code :type (or (string 5) db-null) + :constraint 'firstkey :primary-key 't) + (title :type (varchar 40)) + (did :type integer) + (date-prod :type (or date db-null)) + (kind :type (or (varchar 10) db-null)) + (len :type (or interval db-null) + :interval :hour-to-minute)) + (:constraint code-title :primary-key code title))) "CREATE TABLE films (code CHAR(5) CONSTRAINT firstkey PRIMARY KEY , title VARCHAR(40) NOT NULL, did INTEGER NOT NULL, date_prod DATE, kind VARCHAR(10), len INTERVAL HOUR TO MINUTE, CONSTRAINT code_title PRIMARY KEY (code, title))")) ;; Define a primary key constraint for table distributors using table constraint syntax - (is (equal (sql (:create-table 'distributors - ((did :type (or integer db-null) :check (:> 'did 100)) - (name :type (or (varchar 40) db-null))) - (:primary-key did))) - "CREATE TABLE distributors (did INTEGER CHECK (did > 100), name VARCHAR(40), PRIMARY KEY (did))")) + (is (equal + (sql (:create-table 'distributors + ((did :type (or integer db-null) :check (:> 'did 100)) + (name :type (or (varchar 40) db-null))) + (:primary-key did))) + "CREATE TABLE distributors (did INTEGER CHECK (did > 100), name VARCHAR(40), PRIMARY KEY (did))")) ;; Define a primary key constraint for table distributors using column constraint syntax @@ -299,10 +324,14 @@ "CREATE TABLE distributors (did INTEGER PRIMARY KEY , name VARCHAR(40))")) ;; Assign a literal constant default value for the column name, arrange for the default value of column did to be generated by selecting the next value of a sequence object, and make the default value of modtime be the time at which the row is inserted: - (is (equal (sql (:create-table 'distributors - ((name :type (or (varchar 40) db-null) :default "Luso Films") - (did :type (or integer db-null) :default (:nextval "distributors-serial")) - (modtime :type (or timestamp db-null) :default (:current-timestamp))))) + (is (equal (sql + (:create-table 'distributors + ((name :type (or (varchar 40) db-null) + :default "Luso Films") + (did :type (or integer db-null) + :default (:nextval "distributors-serial")) + (modtime :type (or timestamp db-null) + :default (:current-timestamp))))) "CREATE TABLE distributors (name VARCHAR(40) DEFAULT E'Luso Films', did INTEGER DEFAULT nextval(E'distributors_serial'), modtime TIMESTAMP DEFAULT current_timestamp)")) ;; Define a table with a timestamp with and without a time zones @@ -312,10 +341,12 @@ (grant-date :type (or timestamp-without-time-zone db-null))))) "CREATE TABLE account_role (user_id INTEGER NOT NULL, role_id INTEGER NOT NULL, grant_date TIMESTAMP WITHOUT TIME ZONE)")) - (is (equal (sql (:create-table 'account-role - ((user-id :type integer) - (role-id :type integer) - (grant-date :type (or timestamp-with-time-zone db-null))))) + (is (equal + (sql (:create-table 'account-role + ((user-id :type integer) + (role-id :type integer) + (grant-date + :type (or timestamp-with-time-zone db-null))))) "CREATE TABLE account_role (user_id INTEGER NOT NULL, role_id INTEGER NOT NULL, grant_date TIMESTAMP WITH TIME ZONE)")) (is (equal (sql (:create-table 'account-role @@ -366,8 +397,9 @@ "CREATE TABLE distributors (did INTEGER, name VARCHAR(40), UNIQUE (name, did))")) ;; Create a composite type and a typed table: - (is (equal (sql (:create-composite-type 'employee-type (name text) (salary numeric) )) - "(CREATE TYPE employee_type AS (name text, salary numeric)")) + (is (equal (sql (:create-composite-type 'employee-type (name text) + (salary numeric) )) + "(CREATE TYPE employee_type AS (name TEXT, salary NUMERIC)")) ;; Create the same table, specifying 70% fill factor for both the table and its unique index: @@ -438,13 +470,24 @@ "CREATE TABLE account_role (user_id INTEGER NOT NULL, role_id INTEGER NOT NULL, grant_date TIMESTAMP WITHOUT TIME ZONE, PRIMARY KEY (user_id, role_id), CONSTRAINT account_role_role_id_fkey FOREIGN KEY (role_id) REFERENCES role(role_id) MATCH SIMPLE ON DELETE RESTRICT ON UPDATE RESTRICT, CONSTRAINT account_role_user_id_fkey FOREIGN KEY (user_id) REFERENCES users(user_id) MATCH SIMPLE ON DELETE RESTRICT ON UPDATE RESTRICT)"))) (test create-table-generated-always - "Testing generated always column" + "Testing generated always column. See https://www.postgresql.org/docs/current/ddl-generated-columns.html for Postgresql Documentation." (is (equal (sql (:create-table 't10 ((title :type (or text db-null)) (body :type (or text db-null)) (tsv :type (or tsvector db-null) - :generated-always ((:to-tsvector "english" 'body)))))) - "CREATE TABLE t10 (title TEXT, body TEXT, tsv TSVECTOR GENERATED ALWAYS AS (to_tsvector(E'english', body)) STORED)"))) + :generated-always + (:to-tsvector "english" 'body))))) + "CREATE TABLE t10 (title TEXT, body TEXT, tsv TSVECTOR GENERATED ALWAYS AS (to_tsvector (E'english', body)) STORED)")) + (is (equal + (let ((fx-rate 0.8)) + (sql (:create-table 'cars + ((car-id :type (or int db-null)) + (brand-name :type varchar) + (price-in-dollar :type (or numeric db-null)) + (price-in-pound :type (or numeric db-null) + :generated-always + (:* 'price-in-dollar fx-rate)))))) +"CREATE TABLE cars (car_id INT, brand_name VARCHAR NOT NULL, price_in_dollar NUMERIC, price_in_pound NUMERIC GENERATED ALWAYS AS ((price_in_dollar * 0.8)) STORED)"))) (test create-table-identity "Testing generating identity columns" @@ -469,7 +512,8 @@ "CREATE TABLE t1 (id INT NOT NULL GENERATED BY DEFAULT AS IDENTITY PRIMARY KEY , name VARCHAR NOT NULL)")) (is (equal (sql (:create-table 't1 ((w :type (or real db-null)) (h :type (or real db-null)) - (area :type (or real db-null) :generated-always ((:* w h)))))) + (area :type (or real db-null) + :generated-always (:* 'w 'h))))) "CREATE TABLE t1 (w REAL, h REAL, area REAL GENERATED ALWAYS AS ((w * h)) STORED)")) (with-test-connection @@ -913,7 +957,7 @@ :collate "en_US.utf8")) "ALTER TABLE test2 ALTER COLUMN description TYPE VARCHAR(64) COLLATE \"en_US.utf8\"")) ;; change type timestamp with quoted table and column - (is (equal (sql (:alter-table 'test2 :alter-column 'time :type (or :timestamp-with-time-zone db-null))) + (is (equal (sql (:alter-table 'test2 :alter-column 'time :type (or timestamp-with-time-zone db-null))) "ALTER TABLE test2 ALTER COLUMN time TYPE TIMESTAMP WITH TIME ZONE")) ;; To remove a default constraint from a column (is (equal (sql (:alter-table 'distributors :alter-column 'street :drop-default)) @@ -948,4 +992,4 @@ "CREATE TABLE geo (geom GEOMETRY)")) (is (equal (sql (:create-table geo ((geom :type (or s-sql:db-null (geometry point 4326)))))) - "CREATE TABLE geo (geom geometry (POINT, 4326))"))) + "CREATE TABLE geo (geom GEOMETRY(POINT, 4326))"))) diff --git a/s-sql/tests/tests.lisp b/s-sql/tests/tests.lisp index c22047e..72273c1 100644 --- a/s-sql/tests/tests.lisp +++ b/s-sql/tests/tests.lisp @@ -288,10 +288,32 @@ name." "RATIO")) (is (equal (sql-type-name 'float) "REAL")) + (signals error (sql-type-name '(A))) + (signals error (sql-type-name 'array)) (is (equal (sql-type-name 'array 'integer) "INTEGER[]")) - (signals error (sql-type-name 'array "boulder"))) + (signals error (sql-type-name 'array "boulder")) + (is (equal (s-sql:sql-type-name 'A) + "A")) + (is (equal (sql-type-name 'int) + "INT")) + (is (equal (sql-type-name 'integer) + "INTEGER")) + (is (equal (sql-type-name 'numeric 2 3) + "NUMERIC(2, 3)")) + (is (equal (sql-type-name 'numeric) + "NUMERIC")) + (is (equal (sql-type-name 'vector 2 3) + "VECTOR(2, 3)")) + (is (equal (s-sql::to-type-name 'some-symbol) + "SOME_SYMBOL")) + (is (equal (s-sql:sql-type-name 'some-symbol 1 3) + "SOME_SYMBOL(1, 3)")) + (is (equal (s-sql::sql-type-name 'timestamp-with-time-zone) + "TIMESTAMP WITH TIME ZONE")) + (is (equal (s-sql::sql-type-name 'timestamp-without-time-zone) + "TIMESTAMP WITHOUT TIME ZONE"))) (test to-type-name "Testing to-type-name. Turn a Lisp type expression into an SQL typename." @@ -299,9 +321,31 @@ name." "REAL")) (is (equal (s-sql::to-type-name '(string "5")) "CHAR(5)")) + (is (equal (s-sql::to-type-name '(string 5)) + "CHAR(5)")) (is (equal (let ((name 'float)) (s-sql::to-type-name name)) "REAL")) - (signals error (let ((name "float")) (s-sql::to-type-name name)))) + (is (equal (s-sql::to-type-name 'double-float) + "DOUBLE PRECISION")) + (is (equal (s-sql::to-type-name '(double-float 3 2)) + "DOUBLE PRECISION")) + (is (equal (s-sql::to-type-name '(numeric 3 2)) + "NUMERIC(3, 2)")) + (is (equal (s-sql::to-type-name (list 'numeric 3 2)) + "NUMERIC(3, 2)")) + (signals error (let ((name "float")) + (s-sql::to-type-name name))) + (is (equal (s-sql::to-type-name 'some-symbol) + "SOME_SYMBOL")) + ;; Note in the following result that the string is not denominated as a string. + (is (equal (s-sql::to-type-name '(some-symbol "amber" 3)) + "SOME_SYMBOL(amber, 3)")) + (is (equal (s-sql::to-type-name '(:vector 3)) + "VECTOR(3)")) + (is (equal (s-sql::to-type-name '(:vector 3 5)) + "VECTOR(3, 5)")) + (is (equal (s-sql::sql-type-name 'timestamp-without-time-zone) + "TIMESTAMP WITHOUT TIME ZONE"))) (test s-sql-string (is (equal (s-sql::to-s-sql-string '("alpha" "beta" "ceta" "Tau")) @@ -418,7 +462,9 @@ to strings \(which will form an SQL query when concatenated)." (is (equal (s-sql::sql-expand '((:default "Triumph"))) '((SQL-ESCAPE ((:DEFAULT "Triumph")))))) (is (equal (s-sql::sql-expand '((:criteria "integers") (:default "Triumph"))) - '((SQL-ESCAPE ((:CRITERIA "integers") (:DEFAULT "Triumph")))) ))) + '((SQL-ESCAPE ((:CRITERIA "integers") (:DEFAULT "Triumph")))) )) + (is (equal (s-sql::sql-expand '((:= fastupdate off) (:= fillfactor 70))) + '((SQL-ESCAPE ((:= FASTUPDATE OFF) (:= FILLFACTOR 70))))))) (test sql-expand-list "Testing sql-expand-list. Expand a list of elements, adding a separator in between them." @@ -492,7 +538,14 @@ to strings \(which will form an SQL query when concatenated)." (test expand-sql-op "Testing expand-sql-op" (is (equal (s-sql::expand-sql-op :max '(1 2 3)) - '("MAX(" "1" ", " "2" ", " "3" ")")))) + '("MAX(" "1" ", " "2" ", " "3" ")"))) + (is (equal (s-sql::expand-sql-op := '(a 2)) + '("(" (SQL-ESCAPE A) " = " "2" ")"))) + (is (equal (s-sql::expand-sql-op := '('a 2)) + '("(" "a" " = " "2" ")"))) + ;; Compiling the test will trigger a warning that variable A is defined and not used. + (is (equal (let ((a 2)) (s-sql::expand-sql-op := '(a 2))) + '("(" (SQL-ESCAPE A) " = " "2" ")")))) (test make-expander "Testing make-expander" @@ -514,6 +567,20 @@ to strings \(which will form an SQL query when concatenated)." (is (equal (funcall (s-sql::make-expander :n-or-unary "unary5") '("like" "a")) '("(" "E'like'" " unary5 " "E'a'" ")")))) +(test create-composite-type + "Testing create-composite-type" + (is (equal (sql (:create-composite-type 'inventory-item + (r double-float) + (i double precision))) + "(CREATE TYPE inventory_item AS (r DOUBLE PRECISION, i DOUBLE PRECISION)")) + (is (equal (sql (:create-composite-type 'inventory-item (r string) (i (numeric 5 2)))) + "(CREATE TYPE inventory_item AS (r TEXT, i NUMERIC(5, 2))")) + (is (equal (sql (:create-composite-type 'inventory-item (r text) (i integer))) + "(CREATE TYPE inventory_item AS (r TEXT, i INTEGER)")) + (is (equal (sql (:create-composite-type 'inventory-item (name string) + (serial-number bigint) (count smallint))) + "(CREATE TYPE inventory_item AS (name TEXT, serial_number BIGINT, count SMALLINT)"))) + (test select-simple "Testing select modifiers" (is (equal (sql (:select 'item :from 'item-table)) @@ -567,6 +634,19 @@ to strings \(which will form an SQL query when concatenated)." (is (equal (sql (:select 'ta :from 'a :where (:not-null 'ta))) "(SELECT ta FROM a WHERE (ta IS NOT NULL))"))) +(test in-itself + (is (equal (sql (:in 'id (:set (list 2 7 8)))) + "(id IN (2, 7, 8))")) + ;; In the following, the quoted list in a real query will cause Postgresql to throw + ;; a syntax error because we double up the parentheses. + (is (equal (sql (:in 'id (:set '(2 7 8)))) + "(id IN ((2, 7, 8)))")) + ;; The solution is to pass the quoted list in as a variable + (is (equal (let ((a (list 2 7 8))) (sql (:in 'id (:set a)))) + "(id IN (2, 7, 8))")) + (is (equal (let ((a '(2 7 8))) (sql (:in 'id (:set a)))) + "(id IN (2, 7, 8))"))) + (test select-in (build-employee-table) (is (equal (sql (:select '* :from 'rental :where (:in 'id '(1 2)))) @@ -577,7 +657,7 @@ to strings \(which will form an SQL query when concatenated)." "(SELECT * FROM table1 WHERE (id IN (1, 2, 3)))")) (is (equal (with-test-connection (query (:select 'id 'name :from 'employee - :where (:in 'id (:select 'id :from 'employee :where (:= 'id 2)))))) + :where (:in 'id (:select 'id :from 'employee :where (:= 'id 2)))))) '((2 "Robert"))))) (test select-not-in @@ -2480,45 +2560,6 @@ To sum the column len of all films and group the results by kind:" (is (equal type "char(5)")) (is (eq null? t)))) -(test create-index - "Testing create-index. Available parameters - in order after name - -are :concurrently, :on, :using, :fields and :where.The advantage to using the -keyword :concurrently is that writes to the table -from other sessions are not locked out while the index is is built. The disadvantage is -that the table will need to be scanned twice. Everything is a trade-off." - (is (equal (sql (:create-index 'films_idx :on 'films :fields 'title)) - "CREATE INDEX films_idx ON films (title)")) - (is (equal (sql (:create-index 'films-idx :on "films" :fields 'title)) - "CREATE INDEX films_idx ON films (title)")) - (is (equal (sql (:create-index 'films-idx :on "films" :fields 'title 'id)) - "CREATE INDEX films_idx ON films (title, id)")) - (is (equal (sql (:create-index 'films_idx :on "films" :using gin :fields 'title)) - "CREATE INDEX films_idx ON films USING gin (title)")) - (is (equal (sql (:create-index 'doc-tags-id-tags - :on "doc-tags-array" :using gin :fields 'tags)) - "CREATE INDEX doc_tags_id_tags ON doc_tags_array USING gin (tags)")) - (is (equal (sql (:create-unique-index 'doc-tags-id-doc-id - :on "doc-tags-array" :fields 'doc-id)) - "CREATE UNIQUE INDEX doc_tags_id_doc_id ON doc_tags_array (doc_id)")) - (is (equal (sql (:create-index 'films-idx :concurrently - :on "films" :using 'btree :fields 'created-at)) - "CREATE INDEX CONCURRENTLY films_idx ON films USING btree (created_at)")) - (is (equal (sql (:create-index 'films-idx :unique :concurrently :on "films" - :using 'btree :fields 'created-at)) - "CREATE UNIQUE INDEX CONCURRENTLY films_idx ON films USING btree (created_at)")) - (is (equal (sql (:create-index (:if-not-exists 'test-uniq-1-idx) - :on test-uniq :fields 'name)) - "CREATE INDEX IF NOT EXISTS test_uniq_1_idx ON test_uniq (name)")) - (with-test-connection - (query (:drop-table :if-exists 'george :cascade)) - (is (eq (table-exists-p 'george) nil)) - (query (:create-table 'george ((id :type integer)))) - (is (eq (table-exists-p 'george) t)) - (query (:create-index 'george-idx :on 'george :fields 'id)) - (is (pomo:index-exists-p 'george-idx)) - (is (pomo:index-exists-p "george-idx")))) - - (test create-view "Testing create-view syntax" (is (equal (sql (:create-view 'quagmire (:select 'id 'name :from 'employee))) @@ -2679,11 +2720,14 @@ that the table will need to be scanned twice. Everything is a trade-off." ("Hit me with your pet shark!") ("He swore he just saw his sushi move.")))) - (is (equalp (query (:select 'id (:regexp-matches 'text "(s[A-z]+)") :from 'text-search)) - '((1 #("son")) (2 #("sly")) (3 #("stupidity")) (4 #("shark")) (5 #("swore"))))) + (is (equalp (query (:select 'id (:regexp-matches 'text "(s[A-z]+)") + :from 'text-search)) + '((1 #("son")) (2 #("sly")) (3 #("stupidity")) (4 #("shark")) + (5 #("swore"))))) (is (equalp (query (:select 'id (:regexp-matches 'text "(s[A-z]+)" "g") :from 'text-search)) - '((1 #("son")) (2 #("sly")) (3 #("stupidity")) (4 #("shark")) (5 #("swore")) + '((1 #("son")) (2 #("sly")) (3 #("stupidity")) (4 #("shark")) + (5 #("swore")) (5 #("st")) (5 #("saw")) (5 #("sushi"))))) (is (equalp (query (:select 'id (:regexp-replace 'text "(s[A-z]+)" "g") :from 'text-search)) @@ -2694,6 +2738,18 @@ that the table will need to be scanned twice. Everything is a trade-off." (is (equalp (query (:select 'id 'text :from 'text-search :where (:~ 'text "sushi"))) '((5 "He swore he just saw his sushi move.")))))) +(test tsvector + (is (equal (sql (:select 'title :from 'pgweb :where (:to-tsvector "english" "friend"))) + "(SELECT title FROM pgweb WHERE to_tsvector (E'english', E'friend'))"))) + +(test tsquery + (is (equal + (sql (:select 'title + :from 'pgweb + :where (:@@ (:to-tsvector "english" 'body) + (:to-tsquery "english" "friend")))) + "(SELECT title FROM pgweb WHERE (to_tsvector (E'english', body) @@ to_tsquery (E'english', E'friend')))"))) + (test variable-parameters (is (equal (let ((column 'latitude)) (sql (:select column :from 'countries))) @@ -2709,6 +2765,7 @@ that the table will need to be scanned twice. Everything is a trade-off." (:= 'regions.name '$2)) (:= 'regions.id 'countries.region-id))))) "(SELECT countries.name FROM countries, regions WHERE (((regions.name = $1) or (regions.name = $2)) and (regions.id = countries.region_id)))")) + ;; Using strings does not work. The tests with strings are simply to flag changes in development results. (is (equal (let ((select "countries.name")) (sql (:select select :from 'countries 'regions @@ -2882,3 +2939,13 @@ that the table will need to be scanned twice. Everything is a trade-off." (build-boolean-table) (is (equal (query (:select '* :from 'boolean-test :where (:is-null 'a))) '((3 :NULL "I am NULL")))))) + +(test call + (is (equal (sql (:call 'set_x_procedure 1 13)) + "CALL set_x_procedure(1, 13)")) + (is (equal (let ((a 1) (b 2)) + (sql (:call 'my-proc a b 3))) + "CALL my_proc(1, 2, 3)")) + (is (equal (let ((a 1) (b 2) (p 'my-proc)) + (sql (:call p a b 3))) + "CALL my_proc(1, 2, 3)")))