r10969: 04 Jul 2006 Kevin Rosenberg <kevin@rosenberg.net>
[clsql/s11.git] / sql / generic-postgresql.lisp
blob5e3e177fb9add4f5f2323b14030bf791d30bab11
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)
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 (NOT (relowner=1))"))
74 (t "")))
76 (defun database-list-objects-of-type (database type owner)
77 (mapcar #'car
78 (database-query
79 (format nil
80 (if (not (eq owner :all))
82 SELECT c.relname
83 FROM pg_catalog.pg_class c
84 LEFT JOIN pg_catalog.pg_roles r ON r.oid = c.relowner
85 LEFT JOIN pg_catalog.pg_namespace n ON n.oid = c.relnamespace
86 WHERE c.relkind IN ('~A','')
87 AND n.nspname NOT IN ('pg_catalog', 'pg_toast')
88 AND pg_catalog.pg_table_is_visible(c.oid)
89 ~A"
90 "SELECT relname FROM pg_class WHERE (relkind =
91 '~A')~A")
92 type
93 (owner-clause owner))
94 database nil nil)))
96 (defmethod database-list-tables ((database generic-postgresql-database)
97 &key (owner nil))
98 (database-list-objects-of-type database "r" owner))
100 (defmethod database-list-views ((database generic-postgresql-database)
101 &key (owner nil))
102 (database-list-objects-of-type database "v" owner))
104 (defmethod database-list-indexes ((database generic-postgresql-database)
105 &key (owner nil))
106 (database-list-objects-of-type database "i" owner))
109 (defmethod database-list-table-indexes (table (database generic-postgresql-database)
110 &key (owner nil))
111 (let ((indexrelids
112 (database-query
113 (format
115 "select indexrelid from pg_index where indrelid=(select relfilenode from pg_class where relname='~A'~A)"
116 (string-downcase table)
117 (owner-clause owner))
118 database :auto nil))
119 (result nil))
120 (dolist (indexrelid indexrelids (nreverse result))
121 (push
122 (caar (database-query
123 (format nil "select relname from pg_class where relfilenode='~A'"
124 (car indexrelid))
125 database nil nil))
126 result))))
128 (defmethod database-list-attributes ((table string)
129 (database generic-postgresql-database)
130 &key (owner nil))
131 (let* ((owner-clause
132 (cond ((stringp owner)
133 (format nil " AND (relowner=(SELECT usesysid FROM pg_user WHERE usename='~A'))" owner))
134 ((null owner) " AND (not (relowner=1))")
135 (t "")))
136 (result
137 (mapcar #'car
138 (database-query
139 (format nil "SELECT attname FROM pg_class,pg_attribute WHERE pg_class.oid=attrelid AND attisdropped = FALSE AND relname='~A'~A"
140 (string-downcase table)
141 owner-clause)
142 database nil nil))))
143 (if result
144 (remove-if #'(lambda (it) (member it '("cmin"
145 "cmax"
146 "xmax"
147 "xmin"
148 "oid"
149 "ctid"
150 ;; kmr -- added tableoid
151 "tableoid") :test #'equal))
152 result))))
154 (defmethod database-attribute-type (attribute (table string)
155 (database generic-postgresql-database)
156 &key (owner nil))
157 (let ((row (car (database-query
158 (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"
159 (string-downcase table)
160 (string-downcase attribute)
161 (owner-clause owner))
162 database nil nil))))
163 (when row
164 (destructuring-bind (typname attlen atttypmod attnull) row
166 (setf attlen (parse-integer attlen :junk-allowed t)
167 atttypmod (parse-integer atttypmod :junk-allowed t))
169 (let ((coltype (ensure-keyword typname))
170 (colnull (if (string-equal "f" attnull) 1 0))
171 collen
172 colprec)
173 (setf (values collen colprec)
174 (case coltype
175 ((:numeric :decimal)
176 (if (= -1 atttypmod)
177 (values nil nil)
178 (values (ash (- atttypmod 4) -16)
179 (boole boole-and (- atttypmod 4) #xffff))))
180 (otherwise
181 (values
182 (cond ((and (= -1 attlen) (= -1 atttypmod)) nil)
183 ((= -1 attlen) (- atttypmod 4))
184 (t attlen))
185 nil))))
186 (values coltype collen colprec colnull))))))
188 (defmethod database-create-sequence (sequence-name
189 (database generic-postgresql-database))
190 (database-execute-command
191 (concatenate 'string "CREATE SEQUENCE " (sql-escape sequence-name))
192 database))
194 (defmethod database-drop-sequence (sequence-name
195 (database generic-postgresql-database))
196 (database-execute-command
197 (concatenate 'string "DROP SEQUENCE " (sql-escape sequence-name)) database))
199 (defmethod database-list-sequences ((database generic-postgresql-database)
200 &key (owner nil))
201 (database-list-objects-of-type database "S" owner))
203 (defmethod database-set-sequence-position (name (position integer)
204 (database generic-postgresql-database))
205 (values
206 (parse-integer
207 (caar
208 (database-query
209 (format nil "SELECT SETVAL ('~A', ~A)" name position)
210 database nil nil)))))
212 (defmethod database-sequence-next (sequence-name
213 (database generic-postgresql-database))
214 (values
215 (parse-integer
216 (caar
217 (database-query
218 (concatenate 'string "SELECT NEXTVAL ('" (sql-escape sequence-name) "')")
219 database nil nil)))))
221 (defmethod database-sequence-last (sequence-name (database generic-postgresql-database))
222 (values
223 (parse-integer
224 (caar
225 (database-query
226 (concatenate 'string "SELECT LAST_VALUE FROM " sequence-name)
227 database nil nil)))))
229 (defun postgresql-database-list (connection-spec type)
230 (destructuring-bind (host name user password) connection-spec
231 (declare (ignore name))
232 (let ((database (database-connect (list host "template1" user password)
233 type)))
234 (unwind-protect
235 (progn
236 (setf (slot-value database 'clsql-sys::state) :open)
237 (mapcar #'car (database-query "select datname from pg_database"
238 database nil nil)))
239 (progn
240 (database-disconnect database)
241 (setf (slot-value database 'clsql-sys::state) :closed))))))
243 (defmethod database-list (connection-spec (type (eql :postgresql)))
244 (postgresql-database-list connection-spec type))
246 (defmethod database-list (connection-spec (type (eql :postgresql-socket)))
247 (postgresql-database-list connection-spec type))
249 #+nil
250 (defmethod database-describe-table ((database generic-postgresql-database) table)
251 ;; MTP: LIST-ATTRIBUTE-TYPES currently executes separate queries for
252 ;; each attribute. It would be more efficient to have a single SQL
253 ;; query return the type data for all attributes. This code is
254 ;; retained as an example of how to do this for PostgreSQL.
255 (database-query
256 (format nil "select a.attname, t.typname
257 from pg_class c, pg_attribute a, pg_type t
258 where c.relname = '~a'
259 and a.attnum > 0
260 and a.attrelid = c.oid
261 and a.atttypid = t.oid"
262 (sql-escape (string-downcase table)))
263 database :auto nil))
265 ;;; Prepared statements
267 (defvar *next-prepared-id-num* 0)
268 (defun next-prepared-id ()
269 (let ((num (incf *next-prepared-id-num*)))
270 (format nil "CLSQL_PS_~D" num)))
272 (defclass postgresql-stmt ()
273 ((database :initarg :database :reader database)
274 (id :initarg :id :reader id)
275 (bindings :initarg :bindings :reader bindings)
276 (field-names :initarg :field-names :accessor stmt-field-names)
277 (result-types :initarg :result-types :reader result-types)))
279 (defun clsql-type->postgresql-type (type)
280 (cond
281 ((in type :int :integer) "INT4")
282 ((in type :short) "INT2")
283 ((in type :bigint) "INT8")
284 ((in type :float :double :number) "NUMERIC")
285 ((and (consp type) (in (car type) :char :varchar)) "VARCHAR")
287 (error 'sql-user-error
288 :message
289 (format nil "Unknown clsql type ~A." type)))))
291 (defun prepared-sql-to-postgresql-sql (sql)
292 ;; FIXME: Convert #\? to "$n". Don't convert within strings
293 (declare (simple-string sql))
294 (with-output-to-string (out)
295 (do ((len (length sql))
296 (param 0)
297 (in-str nil)
298 (pos 0 (1+ pos)))
299 ((= len pos))
300 (declare (fixnum len param pos))
301 (let ((c (schar sql pos)))
302 (declare (character c))
303 (cond
304 ((or (char= c #\") (char= c #\'))
305 (setq in-str (not in-str))
306 (write-char c out))
307 ((and (char= c #\?) (not in-str))
308 (write-char #\$ out)
309 (write-string (write-to-string (incf param)) out))
311 (write-char c out)))))))
313 (defmethod database-prepare (sql-stmt types (database generic-postgresql-database) result-types field-names)
314 (let ((id (next-prepared-id)))
315 (database-execute-command
316 (format nil "PREPARE ~A (~{~A~^,~}) AS ~A"
318 (mapcar #'clsql-type->postgresql-type types)
319 (prepared-sql-to-postgresql-sql sql-stmt))
320 database)
321 (make-instance 'postgresql-stmt
322 :id id
323 :database database
324 :result-types result-types
325 :field-names field-names
326 :bindings (make-list (length types)))))
328 (defmethod database-bind-parameter ((stmt postgresql-stmt) position value)
329 (setf (nth (1- position) (bindings stmt)) value))
331 (defun binding-to-param (binding)
332 (typecase binding
333 (string
334 (concatenate 'string "'" (sql-escape-quotes binding) "'"))
336 binding)))
338 (defmethod database-run-prepared ((stmt postgresql-stmt))
339 (with-slots (database id bindings field-names result-types) stmt
340 (let ((query (format nil "EXECUTE ~A (~{~A~^,~})"
341 id (mapcar #'binding-to-param bindings))))
342 (cond
343 ((and field-names (not (consp field-names)))
344 (multiple-value-bind (res names)
345 (database-query query database result-types field-names)
346 (setf field-names names)
347 (values res names)))
348 (field-names
349 (values (nth-value 0 (database-query query database result-types nil))
350 field-names))
352 (database-query query database result-types field-names))))))
354 ;;; Capabilities
356 (defmethod db-type-has-fancy-math? ((db-type (eql :postgresql)))
359 (defmethod db-type-default-case ((db-type (eql :postgresql)))
360 :lower)
362 (defmethod db-type-has-prepared-stmt? ((db-type (eql :postgresql)))
365 (defmethod db-type-has-prepared-stmt? ((db-type (eql :postgresql-socket)))