Use :verbose nil for asdf:operate invocation
[clsql/s11.git] / sql / generic-postgresql.lisp
blob370c63352eeeb95b633394f7f1ee7185bf8db51b
1 ;;;; -*- Mode: LISP; Syntax: ANSI-Common-Lisp; Base: 10 -*-
2 ;;;; *************************************************************************
3 ;;;;
4 ;;;; $Id$
5 ;;;;
6 ;;;; Generic postgresql layer, used by db-postgresql and db-postgresql-socket
7 ;;;;
8 ;;;; This file is part of CLSQL.
9 ;;;;
10 ;;;; CLSQL users are granted the rights to distribute and use this software
11 ;;;; as governed by the terms of the Lisp Lesser GNU Public License
12 ;;;; (http://opensource.franz.com/preamble.html), also known as the LLGPL.
13 ;;;; *************************************************************************
15 (in-package #:clsql-sys)
17 (defclass generic-postgresql-database (database)
18 ((has-table-pg_roles :type boolean :reader has-table-pg_roles :initform nil))
19 (:documentation "Encapsulate same behavior across postgresql and postgresql-socket backends."))
23 ;; Object functions
25 (defmethod database-get-type-specifier (type args database
26 (db-type (eql :postgresql)))
27 (declare (ignore type args database))
28 "VARCHAR")
30 (defmethod database-get-type-specifier ((type (eql 'string)) args database
31 (db-type (eql :postgresql)))
32 (declare (ignore database))
33 (if args
34 (format nil "CHAR(~A)" (car args))
35 "VARCHAR"))
37 (defmethod database-get-type-specifier ((type (eql 'tinyint)) args database
38 (db-type (eql :postgresql)))
39 (declare (ignore args database))
40 "INT2")
42 (defmethod database-get-type-specifier ((type (eql 'smallint)) args database
43 (db-type (eql :postgresql)))
44 (declare (ignore args database))
45 "INT2")
47 (defmethod database-get-type-specifier ((type (eql 'wall-time)) args database
48 (db-type (eql :postgresql)))
49 (declare (ignore args database))
50 "TIMESTAMP WITHOUT TIME ZONE")
52 (defmethod database-get-type-specifier ((type (eql 'number)) args database
53 (db-type (eql :postgresql)))
54 (declare (ignore database))
55 (cond
56 ((and (consp args) (= (length args) 2))
57 (format nil "NUMERIC(~D,~D)" (first args) (second args)))
58 ((and (consp args) (= (length args) 1))
59 (format nil "NUMERIC(~D)" (first args)))
61 "NUMERIC")))
63 ;;; Backend functions
65 (defun owner-clause (owner)
66 (cond
67 ((stringp owner)
68 (format
69 nil
70 " AND (relowner=(SELECT usesysid FROM pg_user WHERE (usename='~A')))"
71 owner))
72 ((null owner)
73 (format nil " AND (relowner<>(SELECT usesysid FROM pg_user WHERE usename='postgres'))"))
74 (t "")))
76 (defun has-table (name database)
77 (let ((name-retrieved
78 (caar (database-query
79 (format nil "SELECT relname FROM pg_class WHERE relname='~A'"
80 name)
81 database nil nil))))
82 (if (and (stringp name-retrieved) (plusp (length name-retrieved)))
84 nil)))
86 (defmethod slot-unbound (class (obj generic-postgresql-database)
87 (slot (eql 'has-table-pg_roles)))
88 ;; Lazily cache slot value
89 (declare (ignore class))
90 (setf (slot-value obj 'has-table-pg_roles) (has-table "pg_roles" obj)))
92 (defun database-list-objects-of-type (database type owner)
93 (mapcar #'car
94 (database-query
95 (format nil
96 (if (and (has-table-pg_roles database)
97 (not (eq owner :all)))
99 SELECT c.relname
100 FROM pg_catalog.pg_class c
101 LEFT JOIN pg_catalog.pg_roles r ON r.oid = c.relowner
102 LEFT JOIN pg_catalog.pg_namespace n ON n.oid = c.relnamespace
103 WHERE c.relkind IN ('~A','')
104 AND n.nspname NOT IN ('pg_catalog', 'pg_toast')
105 AND pg_catalog.pg_table_is_visible(c.oid)
107 "SELECT relname FROM pg_class WHERE (relkind =
108 '~A')~A")
109 type
110 (owner-clause owner))
111 database nil nil)))
113 (defmethod database-list-tables ((database generic-postgresql-database)
114 &key (owner nil))
115 (database-list-objects-of-type database "r" owner))
117 (defmethod database-list-views ((database generic-postgresql-database)
118 &key (owner nil))
119 (database-list-objects-of-type database "v" owner))
121 (defmethod database-list-indexes ((database generic-postgresql-database)
122 &key (owner nil))
123 (database-list-objects-of-type database "i" owner))
126 (defmethod database-list-table-indexes (table (database generic-postgresql-database)
127 &key (owner nil))
128 (let ((indexrelids
129 (database-query
130 (format
132 "select indexrelid from pg_index where indrelid=(select relfilenode from pg_class where relname='~A'~A)"
133 (string-downcase table)
134 (owner-clause owner))
135 database :auto nil))
136 (result nil))
137 (dolist (indexrelid indexrelids (nreverse result))
138 (push
139 (caar (database-query
140 (format nil "select relname from pg_class where relfilenode='~A'"
141 (car indexrelid))
142 database nil nil))
143 result))))
145 (defmethod database-list-attributes ((table string)
146 (database generic-postgresql-database)
147 &key (owner nil))
148 (let* ((owner-clause
149 (cond ((stringp owner)
150 (format nil " AND (relowner=(SELECT usesysid FROM pg_user WHERE usename='~A'))" owner))
151 ((null owner) " AND (not (relowner=1))")
152 (t "")))
153 (result
154 (mapcar #'car
155 (database-query
156 (format nil "SELECT attname FROM pg_class,pg_attribute WHERE pg_class.oid=attrelid AND attisdropped = FALSE AND relname='~A'~A"
157 (string-downcase table)
158 owner-clause)
159 database nil nil))))
160 (if result
161 (remove-if #'(lambda (it) (member it '("cmin"
162 "cmax"
163 "xmax"
164 "xmin"
165 "oid"
166 "ctid"
167 ;; kmr -- added tableoid
168 "tableoid") :test #'equal))
169 result))))
171 (defmethod database-attribute-type (attribute (table string)
172 (database generic-postgresql-database)
173 &key (owner nil))
174 (let ((row (car (database-query
175 (format nil "SELECT pg_type.typname,pg_attribute.attlen,pg_attribute.atttypmod,pg_attribute.attnotnull FROM pg_type,pg_class,pg_attribute WHERE pg_class.oid=pg_attribute.attrelid AND pg_class.relname='~A' AND pg_attribute.attname='~A' AND pg_attribute.atttypid=pg_type.oid~A"
176 (string-downcase table)
177 (string-downcase attribute)
178 (owner-clause owner))
179 database nil nil))))
180 (when row
181 (destructuring-bind (typname attlen atttypmod attnull) row
183 (setf attlen (parse-integer attlen :junk-allowed t)
184 atttypmod (parse-integer atttypmod :junk-allowed t))
186 (let ((coltype (ensure-keyword typname))
187 (colnull (if (string-equal "f" attnull) 1 0))
188 collen
189 colprec)
190 (setf (values collen colprec)
191 (case coltype
192 ((:numeric :decimal)
193 (if (= -1 atttypmod)
194 (values nil nil)
195 (values (ash (- atttypmod 4) -16)
196 (boole boole-and (- atttypmod 4) #xffff))))
197 (otherwise
198 (values
199 (cond ((and (= -1 attlen) (= -1 atttypmod)) nil)
200 ((= -1 attlen) (- atttypmod 4))
201 (t attlen))
202 nil))))
203 (values coltype collen colprec colnull))))))
205 (defmethod database-create-sequence (sequence-name
206 (database generic-postgresql-database))
207 (database-execute-command
208 (concatenate 'string "CREATE SEQUENCE " (sql-escape sequence-name))
209 database))
211 (defmethod database-drop-sequence (sequence-name
212 (database generic-postgresql-database))
213 (database-execute-command
214 (concatenate 'string "DROP SEQUENCE " (sql-escape sequence-name)) database))
216 (defmethod database-list-sequences ((database generic-postgresql-database)
217 &key (owner nil))
218 (database-list-objects-of-type database "S" owner))
220 (defmethod database-set-sequence-position (name (position integer)
221 (database generic-postgresql-database))
222 (values
223 (parse-integer
224 (caar
225 (database-query
226 (format nil "SELECT SETVAL ('~A', ~A)" name position)
227 database nil nil)))))
229 (defmethod database-sequence-next (sequence-name
230 (database generic-postgresql-database))
231 (values
232 (parse-integer
233 (caar
234 (database-query
235 (concatenate 'string "SELECT NEXTVAL ('" (sql-escape sequence-name) "')")
236 database nil nil)))))
238 (defmethod database-sequence-last (sequence-name (database generic-postgresql-database))
239 (values
240 (parse-integer
241 (caar
242 (database-query
243 (concatenate 'string "SELECT LAST_VALUE FROM " sequence-name)
244 database nil nil)))))
246 (defun postgresql-database-list (connection-spec type)
247 (destructuring-bind (host name &rest other-args) connection-spec
248 (declare (ignore name))
249 (let ((database (database-connect (list* host "template1" other-args)
250 type)))
251 (unwind-protect
252 (progn
253 (setf (slot-value database 'clsql-sys::state) :open)
254 (mapcar #'car (database-query "select datname from pg_database"
255 database nil nil)))
256 (progn
257 (database-disconnect database)
258 (setf (slot-value database 'clsql-sys::state) :closed))))))
260 (defmethod database-list (connection-spec (type (eql :postgresql)))
261 (postgresql-database-list connection-spec type))
263 (defmethod database-list (connection-spec (type (eql :postgresql-socket)))
264 (postgresql-database-list connection-spec type))
266 #+nil
267 (defmethod database-describe-table ((database generic-postgresql-database) table)
268 ;; MTP: LIST-ATTRIBUTE-TYPES currently executes separate queries for
269 ;; each attribute. It would be more efficient to have a single SQL
270 ;; query return the type data for all attributes. This code is
271 ;; retained as an example of how to do this for PostgreSQL.
272 (database-query
273 (format nil "select a.attname, t.typname
274 from pg_class c, pg_attribute a, pg_type t
275 where c.relname = '~a'
276 and a.attnum > 0
277 and a.attrelid = c.oid
278 and a.atttypid = t.oid"
279 (sql-escape (string-downcase table)))
280 database :auto nil))
282 ;;; Prepared statements
284 (defvar *next-prepared-id-num* 0)
285 (defun next-prepared-id ()
286 (let ((num (incf *next-prepared-id-num*)))
287 (format nil "CLSQL_PS_~D" num)))
289 (defclass postgresql-stmt ()
290 ((database :initarg :database :reader database)
291 (id :initarg :id :reader id)
292 (bindings :initarg :bindings :reader bindings)
293 (field-names :initarg :field-names :accessor stmt-field-names)
294 (result-types :initarg :result-types :reader result-types)))
296 (defun clsql-type->postgresql-type (type)
297 (cond
298 ((in type :int :integer) "INT4")
299 ((in type :short) "INT2")
300 ((in type :bigint) "INT8")
301 ((in type :float :double :number) "NUMERIC")
302 ((and (consp type) (in (car type) :char :varchar)) "VARCHAR")
304 (error 'sql-user-error
305 :message
306 (format nil "Unknown clsql type ~A." type)))))
308 (defun prepared-sql-to-postgresql-sql (sql)
309 ;; FIXME: Convert #\? to "$n". Don't convert within strings
310 (declare (simple-string sql))
311 (with-output-to-string (out)
312 (do ((len (length sql))
313 (param 0)
314 (in-str nil)
315 (pos 0 (1+ pos)))
316 ((= len pos))
317 (declare (fixnum len param pos))
318 (let ((c (schar sql pos)))
319 (declare (character c))
320 (cond
321 ((or (char= c #\") (char= c #\'))
322 (setq in-str (not in-str))
323 (write-char c out))
324 ((and (char= c #\?) (not in-str))
325 (write-char #\$ out)
326 (write-string (write-to-string (incf param)) out))
328 (write-char c out)))))))
330 (defmethod database-prepare (sql-stmt types (database generic-postgresql-database) result-types field-names)
331 (let ((id (next-prepared-id)))
332 (database-execute-command
333 (format nil "PREPARE ~A (~{~A~^,~}) AS ~A"
335 (mapcar #'clsql-type->postgresql-type types)
336 (prepared-sql-to-postgresql-sql sql-stmt))
337 database)
338 (make-instance 'postgresql-stmt
339 :id id
340 :database database
341 :result-types result-types
342 :field-names field-names
343 :bindings (make-list (length types)))))
345 (defmethod database-bind-parameter ((stmt postgresql-stmt) position value)
346 (setf (nth (1- position) (bindings stmt)) value))
348 (defun binding-to-param (binding)
349 (typecase binding
350 (string
351 (concatenate 'string "'" (sql-escape-quotes binding) "'"))
353 binding)))
355 (defmethod database-run-prepared ((stmt postgresql-stmt))
356 (with-slots (database id bindings field-names result-types) stmt
357 (let ((query (format nil "EXECUTE ~A (~{~A~^,~})"
358 id (mapcar #'binding-to-param bindings))))
359 (cond
360 ((and field-names (not (consp field-names)))
361 (multiple-value-bind (res names)
362 (database-query query database result-types field-names)
363 (setf field-names names)
364 (values res names)))
365 (field-names
366 (values (nth-value 0 (database-query query database result-types nil))
367 field-names))
369 (database-query query database result-types field-names))))))
371 ;;; Capabilities
373 (defmethod db-type-has-fancy-math? ((db-type (eql :postgresql)))
376 (defmethod db-type-default-case ((db-type (eql :postgresql)))
377 :lower)
379 (defmethod db-type-has-prepared-stmt? ((db-type (eql :postgresql)))
382 (defmethod db-type-has-prepared-stmt? ((db-type (eql :postgresql-socket)))