diff --git a/CHANGELOG.md b/CHANGELOG.md
index 302b195e..2f583e7d 100644
--- a/CHANGELOG.md
+++ b/CHANGELOG.md
@@ -1,4 +1,114 @@
-# Changelog v. 1.32.1
+# Changelog v. 1.32.8
+S-SQL Enhancements
+
+## :Update
+without the :columns parameter, :update requires alternating column value like so:
+
+ (query (: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))
+
+:update now accepts a :columns parameter. This allows the use of either :set or :select (both of which need to be enclosed in a form) to provide the values, allowing update queries like:
+
+ (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"))))
+
+ (query (:update 't1
+ :columns 'database-name 'encoding
+ (:select 'x.datname 'x.encoding
+ :from (:as 'pg-database 'x)
+ :where (:= 'x.oid 't1.oid))))
+
+## :Insert-into
+Insert-into also now accepts a :columns parameter which allows more precise use of select to insert values into specific row(s). A sample query could look like:
+
+ (query (:insert-into 't11
+ :columns 'region 'subregion 'country
+ (:select (:as 'region-name 'region)
+ (:as 'sub-region-name 'subregion)
+ 'country
+ :from 'regions)))
+
+## Joins
+### Lateral Joins
+Joins are now expanded to include lateral joins. So addition join types are
+
+- :join-lateral (best practice is still to be specific on what kind of join you want)
+- :left-join-lateral
+- :right-join-lateral
+- :inner-join-lateral
+- :outer-join-lateral
+- :cross-join-lateral
+
+### Ordinality
+Selects can now 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.
+
+ (query (:select '*
+ :from (:generate-series 4 1 -1)
+ :with-ordinality))
+
+
+ (query (:select 't1.*
+ :from (:json-object-keys "{\"a1\":\"1\",\"a2\":\"2\",\"a3\":\"3\"}")
+ :with-ordinality-as (:t1 'keys 'n)
+
+
+## New Utility copy-from-csv
+Just a convenience function. It runs the psql copy command from inside lisp using uiop:run-program
+
+# Changelog v. 1.32.7
+
+Additional capabilities for s-sql functions :insert-into and :insert-rows-into
+
+Specifically, both can now use:
+
+- overriding-system-value
+- overriding-user-value
+- on-conflict-do-nothing
+- on-conflict
+- on-conflict-on-constraint
+- on-conflict-update
+- do-nothing
+- update-set
+- from
+- where
+- returning
+
+See updated s-sql docs for examples.
+
+# Changelog v. 1.32.4
+
+Added the ability to return results as json-encoded results as follows:
+
+- :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\"}")
+
+- :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\"}"
+
+- :Json-array-str
+Return a string containing a json array, each element in the array is a selected row expressed as a json object
+
+ (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\"}]"
+
+# Changelog v. 1.32.3
+
+Added flag to avoid SSL certificate verification if required by user
## Fix S-SQL issue 239 (:drop-table ...) expanded incorrectly
diff --git a/README.md b/README.md
index e4b0d230..3567d681 100644
--- a/README.md
+++ b/README.md
@@ -1,7 +1,7 @@
# Postmodern
A Common Lisp PostgreSQL programming interface
---
-Version 1.32
+Version 1.38
Postmodern is a Common Lisp library for interacting with [PostgreSQL](http://www.postgresql.org) databases. It is under active development. Features are:
@@ -19,6 +19,13 @@ The biggest differences between this library and CLSQL/CommonSQL or cl-dbi are t
* [License](#dependencies)
* [Download and installation](#download-and-installation)
* [Quickstart](#quickstart)
+* [Authentication](#authentication)
+* [Reference](#reference)
+* [Data types](#data-types)
+* [Portability](#portability)
+* [Reserved Words](#reserved-words)
+* [Feature Requests](#feature-requests)
+* [Resources](#resources)
* [Running tests](#running-tests)
* [Reference](#reference)
* [Caveats and to-dos](#caveats-and-to-dos)
@@ -419,9 +426,8 @@ The reference manuals for the different components of Postmodern are kept in sep
- [Simple-date](https://marijnhaverbeke.nl/postmodern/simple-date.html)
- [CL-postgres](https://marijnhaverbeke.nl/postmodern/cl-postgres.html)
-## Data Types, Caveats and to-dos
+## Data Types
---
-### Data Types
For a short comparison of lisp and Postgresql data types (date and time datatypes are described in the next section)
@@ -551,7 +557,7 @@ the same sample data looks like:
| timestamp\_without\_timezone | 2020-05-16T05:47:33.315622-04:00 | TIMESTAMP |
| timestamp\_with\_timezone | 2020-05-16T09:47:27.855146-04:00 | TIMESTAMP |
-### Portability
+## Portability
The Lisp code in Postmodern is theoretically portable across implementations,
and seems to work on all major ones as well as some minor ones such as Genera.
It is regularly tested on ccl, sbcl, ecl and cmucl. ABCL currently has issues with utf-8 and :null.
@@ -560,7 +566,7 @@ Please let us know if it does not work on the implementation that you normally u
The library is not likely to work for PostgreSQL versions older than 8.4. Other features only work in newer Postgresql versions as the features were only introduced in those newer versions.
-### Reserved Words
+## Reserved Words
It is highly suggested that you do not use words that are reserved by Postgresql as identifiers (e.g. table names, columns). The reserved words are:
"all" "analyse" "analyze" "and" "any" "array" "as" "asc" "asymmetric"
@@ -577,12 +583,10 @@ It is highly suggested that you do not use words that are reserved by Postgresql
"similar" "some" "symmetric" "table" "then" "to" "trailing" "true" "union"
"unique" "user" "using" "variadic" "verbose" "when" "where" "window" "with"
-### Things that could be implemented
+## Feature Requests
Postmodern is under active development 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
---
- [Mailing List](https://mailman.common-lisp.net/listinfo/postmodern-devel)
diff --git a/ROADMAP.md b/ROADMAP.md
index 2929999f..1103e18c 100644
--- a/ROADMAP.md
+++ b/ROADMAP.md
@@ -1,4 +1,4 @@
-# Roadmap
+# 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
@@ -13,13 +13,10 @@ 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
-- [ ] Hypothetical Set Aggregates Functions (rank, dense-rank, percent-rank, cume-dist)
- [ ] 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)))
-- [ ] Generate-Series needs testing and interval work
-- [ ] Lateral Join (postgresql 9.3)
- [ ] 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/)
@@ -27,11 +24,10 @@ No guarantee is given with respect to resolution or timing on any item.
- [ ] 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)
-- [ ] WITH ORDINALITY clause (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
-- [ ] Multiple row upserts
-- [ ] Crosstabview support (postgresql 9.6)
+- [ ] Create table by selecting from another table.
## Data type support
- [ ] json, jsonb (postgresql 9.4, full text search support in postgresql 10) See
@@ -76,7 +72,7 @@ No guarantee is given with respect to resolution or timing on any item.
## Security Audit
-## Long Range
+## Long Range (Likely Never)
- [ ] Consider extending dao into more ORM capability
- [ ] Multi-Cluster Support
- [ ] Replication Support
diff --git a/cl-postgres.asd b/cl-postgres.asd
index b068da8c..cbd2b694 100644
--- a/cl-postgres.asd
+++ b/cl-postgres.asd
@@ -16,7 +16,7 @@
:author "Marijn Haverbeke Table of Contents
Table of Contents
Table of Contents
is all that is needed to produce the final SQL query.
→ string @@ -485,8 +488,8 @@
→ string @@ -518,8 +521,8 @@
In cases where you do need to build the query at run time, yet you do not @@ -532,8 +535,8 @@
Modifies the current readtable to add a #Q syntax that is read as (sql …). @@ -541,8 +544,8 @@
→ string @@ -561,8 +564,8 @@
→ string @@ -588,16 +591,16 @@
When converting symbols to strings, whether to downcase the symbols is set here. The default is to downcase symbols.
Used to configure whether S-SQL will use standard SQL strings (just replace #\' with ''), or backslash-style escaping. Setting this to NIL is always safe, but when the server is configured to allow standard strings (compile-time parameter 'standard_conforming_strings' is 'on', which will become the default in future versions of PostgreSQL), the noise in queries can be reduced by setting this to T. @@ -605,8 +608,8 @@
A set of all Postgresql's reserved words, for automatic escaping. Probably not a good idea to use these words as identifiers anyway. @@ -625,8 +628,8 @@
Determines whether double quotes are added around column, table, and ** function names in @@ -653,8 +656,8 @@
→ string @@ -666,8 +669,8 @@
→ string @@ -683,8 +686,8 @@
→ keyword @@ -697,8 +700,8 @@
Define simple SQL operators. Arity is one of :unary (like 'not'), :unary-postfix @@ -712,8 +715,8 @@
S-SQL knows the SQL equivalents to a number of Lisp types, and defines some @@ -833,8 +836,8 @@
This is a type of which only the keyword :null is a member. It is used to represent @@ -844,8 +847,8 @@
An S-SQL form is converted to a query through the following rules: @@ -866,8 +869,8 @@
Creates a select query. The arguments are split on the keywords found among @@ -876,19 +879,46 @@
(query (:select 'item :distinct - :from 'item-table - :where (:= 'col1 "Albania"))) + :from 'item-table + :where (:= 'col1 "Albania"))) (query (:select (:+ 'field-1 100) 'field-5 :from (:as 'my-table 'x) @@ -897,29 +927,66 @@:where (:not-null 'a.field-3))) (query (:order-by - (:select 'regions.name - (:count 'regions.name) - :from 'countries 'regions - :where (:= 'regions.id 'countries.region-id) - :group-by 'regions.name) + (:select 'regions.name + (:count 'regions.name) + :from 'countries 'regions + :where (:= 'regions.id 'countries.region-id) + :group-by 'regions.name) 'regions.name)) (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))) + :from (:as 'countries 'c) + :inner-join (:as 'regions 'r) + :on (:= 'c.region-id 'r.id) + :group-by 'r.name + :having (:< (:count 'c.id) 10))) + +(query (:select 'i.* 'p.* + :from (:as 'individual 'i) + :inner-join (:as 'publisher 'p) + :using ('individualid) + :left-join-lateral (:as 'anothertable 'a) + :on (:= 'a.identifier 'i.individualid) + :where (:= 'a.something \"something\"))) + +(query (:select 't1.id 'a.elem 'a.nr + :from (:as 't12 't1) + :left-join (:unnest (:string-to-array 't1.elements ",")) + :with-ordinality-as (:a 'elem 'nr) + :on 't))
+Other examples can be found in s-sql/tests/tests.lisp +
+Allowable join keywords are: +
++The lateral joins will not be discussed separately. +
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." @@ -931,8 +998,8 @@
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. @@ -1001,8 +1068,8 @@
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. @@ -1014,8 +1081,8 @@
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? @@ -1050,16 +1117,16 @@
The following operators are defined:
These are expanded as infix operators. When meaningful, they allow more than @@ -1075,8 +1142,8 @@
Unary operators for bitwise and logical negation. @@ -1196,8 +1263,8 @@
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. @@ -1305,8 +1372,8 @@
Create a stored procedure. The argument and return types are interpreted as @@ -1321,8 +1388,8 @@
Regular expression matching operators. The exclamation mark means 'does not match', @@ -1368,8 +1435,8 @@
Simple SQL string matching operators (:ilike is case-insensitive). @@ -1382,8 +1449,8 @@
Fast Text Search match operator. @@ -1391,8 +1458,8 @@
Used to invert the meaning of an operator in an :order-by clause. @@ -1407,8 +1474,8 @@
Used to determine where :null values appear in an :order-by clause. @@ -1416,8 +1483,8 @@
Also known in some explanations as "alias". This assigns a name to a column or @@ -1472,8 +1539,8 @@
The CAST operator. Takes a query as an argument, and returns the result @@ -1502,8 +1569,8 @@
Is similar to cast but uses the postgresql :: formating. Unlike cast it will not @@ -1521,8 +1588,8 @@
Creates a composite type with a type-name and two or more columns. E.g. @@ -1533,8 +1600,8 @@
The EXISTS operator. Takes a query as an argument, and returns true or false @@ -1554,8 +1621,8 @@
Test whether a value is null. @@ -1566,8 +1633,8 @@
Test whether a value is not null. @@ -1578,8 +1645,8 @@
Test whether a value is in a set of values. @@ -1599,8 +1666,8 @@
Inverse of the above. @@ -1608,8 +1675,8 @@
Denote a set of values. This operator has two interfaces. When @@ -1684,8 +1751,8 @@
This is used when calling a select query into an array. See array-notes.html @@ -1710,8 +1777,8 @@
This is the general operator for arrays. It also handles statements that include @@ -1732,8 +1799,8 @@
Dereference an array value. If end is provided, extract a slice of the array. @@ -1749,8 +1816,8 @@
Extract a field from a date/time value. For example, (:extract :month (:now)). @@ -1769,8 +1836,8 @@
A conditional expression. Clauses should take the form (test value). If @@ -1785,8 +1852,8 @@
Test whether a value lies between two other values. @@ -1800,8 +1867,8 @@
Works like :between, except that the start value is not required to be @@ -1810,8 +1877,8 @@
Can be used to combine multiple names into a name of the form A.B to @@ -1821,8 +1888,8 @@
Add a type declaration to a value, as in in "4.3::real". The second @@ -1835,8 +1902,8 @@
Insert a string as-is into the query. This can be useful for doing things @@ -1853,8 +1920,8 @@
Fetch is a more efficient way to do pagination instead of using limit and @@ -1881,8 +1948,8 @@
In S-SQL limit is not part of the select operator, but an extra @@ -1898,8 +1965,8 @@
Order the results of a query by the given expressions. See :desc for @@ -1916,8 +1983,8 @@
Values computes a row value or set of row values for use in a specific @@ -1952,8 +2019,8 @@
This is a fudge. It returns a string "()" where something like '() @@ -1969,8 +2036,8 @@
https://www.postgresql.org/docs/current/static/queries-table-expressions.html#QUERIES-GROUPING-SETS @@ -1995,8 +2062,8 @@
https://www.postgresql.org/docs/current/static/queries-table-expressions.html#QUERIES-GROUPING-SETS @@ -2016,20 +2083,20 @@
Creates an interval data type, generally represented in postmodern as an alist
(query (:select (:current-date)) :single) @@ -2037,33 +2104,33 @@-
sql-op :current-time ()
+ --sql-op :current-timestamp ()
+ --sql-op :timestamp (arg)
+ --sql-op :age (&rest args)
+ --sql-op :date (arg)
+ --sql-op :make-interval (&rest args)
++sql-op :make-interval (&rest args)
Takes lists of (time-unit value) and returns a timestamp type. Example: @@ -2076,8 +2143,8 @@
-
sql-op :make-timestamp (&rest args)
++sql-op :make-timestamp (&rest args)
Takes lists of (time-unit value) and returns a timestamptz type. Example: @@ -2091,8 +2158,8 @@
-
sql-op :make-timestamptz (&rest args)
++sql-op :make-timestamptz (&rest args)
Takes lists of (time-unit value) and returns a timestamptz type. Example: @@ -2108,12 +2175,12 @@
-
Aggregation Operators
++Aggregation Operators
--sql-op :count (&rest args)
++sql-op :count (&rest args)
Count returns the number of rows for which the expression is not null. @@ -2166,8 +2233,8 @@
-
sql-op :avg (&rest rest args)
++sql-op :avg (&rest rest args)
Avg calculates the average value of a list of values. Note that if the @@ -2182,8 +2249,8 @@
-