From 43f92a49a7a62dcf0ec984f5d0b4fa4164bc4b67 Mon Sep 17 00:00:00 2001
From: Sabra Crolleton
-Version 1.33.9
+Version 1.33.10
@@ -268,6 +268,41 @@ Postmodern
Table of Contents
+
Table of Contents
Table of Contents
Table of Contents
Table of Contents
me. Your mileage may vary.
+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 +
+ + +-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 -
- - -The Simple-date add-on library (not enabled by default) provides types (CLOS classes) for dates, timestamps, and intervals @@ -1637,9 +1638,9 @@
For those who want to use local-time, to enable the local-time reader:
@@ -1796,14 +1797,9 @@-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. -
+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. +
+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 @@
These are expanded as infix operators. When meaningful, they allow more than @@ -1138,6 +1150,21 @@
+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))) ++
(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 +1742,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 +2805,9 @@sql-op :var-samp (&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 +2835,9 @@
Rows-between allows window functions to apply to different segments of a result set. It accepts the following keywords: @@ -3011,9 +3038,9 @@
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 +3723,60 @@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)) -"CREATE INDEX gin_idx ON historical_events USING GIN (data)" +(query (:create-index 'films-idx :on "films" :fields 'title 'id)) + +(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)))
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 +4179,8 @@
This works with insert-into statements as well
@@ -4147,8 +4215,8 @@This works with delete statements as well
@@ -4357,4 +4425,4 @@+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))) ++
+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. +
++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. +
++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;") ++
+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)) ++
+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)) ++
+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. +
++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. +
+(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) + ++
+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))
+
++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)) ++
+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; + $$ ;") ++
(query "call set_x_procedure2(1,11)" :single) + +1 ++
(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; + $$ ;") ++
(query "call set_x_procedure2(1,11)")
+
+((1 11))
+
+(query (:call 'set_x_procedure2 1 13))
+
+((1 13))
+
+