r9403: Rework conditions to be CommonSQL backward compatible
[clsql.git] / db-sqlite / sqlite-sql.lisp
1 ;;;; -*- Mode: LISP; Syntax: ANSI-Common-Lisp; Base: 10 -*-
2 ;;;; *************************************************************************
3 ;;;; FILE IDENTIFICATION
4 ;;;;
5 ;;;; Name:     sqlite-sql.lisp
6 ;;;; Purpose:  High-level SQLite interface
7 ;;;; Authors:  Aurelio Bignoli, Kevin Rosenberg, Marcus Pearce
8 ;;;; Created:  Aug 2003
9 ;;;;
10 ;;;; $Id$
11 ;;;;
12 ;;;; This file, part of CLSQL, is Copyright (c) 2003 by Aurelio Bignoli and
13 ;;;; Copyright (c) 2003-2004 by Kevin Rosenberg and Marcus Pearce.
14 ;;;;
15 ;;;; CLSQL users are granted the rights to distribute and use this software
16 ;;;; as governed by the terms of the Lisp Lesser GNU Public License
17 ;;;; (http://opensource.franz.com/preamble.html), also known as the LLGPL.
18 ;;;; *************************************************************************
19
20 (in-package #:clsql-sqlite)
21
22 (defclass sqlite-database (database)
23   ((sqlite-db :initarg :sqlite-db :accessor sqlite-db)))
24
25 (defmethod database-type ((database sqlite-database))
26   :sqlite)
27
28 (defmethod database-initialize-database-type ((database-type (eql :sqlite)))
29   t)
30
31 (defun check-sqlite-connection-spec (connection-spec)
32   (check-connection-spec connection-spec :sqlite (name)))
33
34 (defmethod database-name-from-spec (connection-spec
35                                     (database-type (eql :sqlite)))
36   (check-sqlite-connection-spec connection-spec)
37   (first connection-spec))
38
39 (defmethod database-connect (connection-spec (database-type (eql :sqlite)))
40   (check-sqlite-connection-spec connection-spec)
41   (handler-case
42       (make-instance 'sqlite-database
43                      :name (database-name-from-spec connection-spec :sqlite)
44                      :database-type :sqlite
45                      :connection-spec connection-spec
46                      :sqlite-db (sqlite:sqlite-open (first connection-spec)))
47     (sqlite:sqlite-error (err)
48       (error 'sql-connection-error
49              :database-type database-type
50              :connection-spec connection-spec
51              :error-id (sqlite:sqlite-error-code err)
52              :message (sqlite:sqlite-error-message err)))))
53
54 (defmethod database-disconnect ((database sqlite-database))
55   (sqlite:sqlite-close (sqlite-db database))
56   (setf (sqlite-db database) nil)
57   t)
58
59 (defmethod database-execute-command (sql-expression (database sqlite-database))
60   (handler-case
61       (multiple-value-bind (data row-n col-n)
62           (sqlite:sqlite-get-table (sqlite-db database) sql-expression)
63         (sqlite:sqlite-free-table data)
64         (unless (= row-n 0)
65           (error 'clsql-simple-warning
66                  :format-control
67                  "Result set not empty: ~@(~A~) row~:P, ~@(~A~) column~:P "
68                  :format-arguments (list row-n col-n))))
69     (sqlite:sqlite-error (err)
70       (error 'sql-database-data-error
71              :database database
72              :expression sql-expression
73              :error-id (sqlite:sqlite-error-code err)
74              :message (sqlite:sqlite-error-message err))))
75   t)
76
77 (defstruct sqlite-result-set
78   (vm (sqlite:make-null-vm)
79       #-clisp :type
80       #-clisp sqlite:sqlite-vm-pointer)
81   (first-row (sqlite:make-null-row)
82              #-clisp :type
83              #-clisp sqlite:sqlite-row-pointer-type)
84   (col-names (sqlite:make-null-row)
85              #-clisp :type
86              #-clisp sqlite:sqlite-row-pointer-type)
87   (result-types nil)
88   (n-col 0 :type fixnum))
89
90 (defmethod database-query (query-expression (database sqlite-database) result-types field-names)
91   (declare (optimize (speed 3) (safety 0) (debug 0) (space 0)))
92   (handler-case
93       (multiple-value-bind (result-set n-col)
94           (database-query-result-set query-expression database
95                                      :result-types result-types
96                                      :full-set nil)
97         (do* ((rows nil)
98               (col-names (when field-names
99                            (loop for j from 0 below n-col
100                                  collect (sqlite:sqlite-aref (sqlite-result-set-col-names result-set) j))))
101               (new-row (make-list n-col) (make-list n-col))
102               (row-ok (database-store-next-row result-set database new-row)
103                       (database-store-next-row result-set database new-row)))
104              ((not row-ok)
105               (values (nreverse rows) col-names))
106           (push new-row rows)))
107     (sqlite:sqlite-error (err)
108       (error 'sql-database-data-error
109              :database database
110              :expression query-expression
111              :error-id (sqlite:sqlite-error-code err)
112              :message (sqlite:sqlite-error-message err)))))
113
114 (defmethod database-query-result-set ((query-expression string)
115                                       (database sqlite-database)
116                                       &key result-types full-set)
117   (handler-case
118       (let ((vm (sqlite:sqlite-compile (sqlite-db database)
119                                        query-expression)))
120         ;;; To obtain column number/datatypes we have to read the first row.
121         (multiple-value-bind (n-col cols col-names)
122             (sqlite:sqlite-step vm)
123           (let ((result-set (make-sqlite-result-set
124                              :vm vm
125                              :first-row cols
126                              :n-col n-col
127                              :col-names col-names
128                              :result-types
129                              (canonicalize-result-types
130                               result-types
131                               n-col
132                               col-names))))
133             (if full-set
134                 (values result-set n-col nil)
135                 (values result-set n-col)))))
136     (sqlite:sqlite-error (err)
137       (error 'sql-database-error
138              :database database
139              :expression query-expression
140              :error-id (sqlite:sqlite-error-code err)
141              :message (sqlite:sqlite-error-message err)))))
142
143 (defun canonicalize-result-types (result-types n-col col-names)
144   (when result-types
145     (let ((raw-types (if (eq :auto result-types)
146                          (loop for j from n-col below (* 2 n-col)
147                                collect (ensure-keyword (sqlite:sqlite-aref col-names j)))
148                          result-types)))
149       (loop for type in raw-types
150             collect
151             (case type
152               ((:int :integer :tinyint :long :bigint)
153                :int32)
154               ((:float :double)
155                :double)
156               ((:numeric)
157                :number)
158               (otherwise
159                :string))))))
160
161 (defmethod database-dump-result-set (result-set (database sqlite-database))
162   (handler-case
163       (sqlite:sqlite-finalize (sqlite-result-set-vm result-set))
164     (sqlite:sqlite-error (err)
165       (error 'clsql-simple-error
166              :format-control "Error finalizing SQLite VM: ~A"
167              :format-arguments (list (sqlite:sqlite-error-message err))))))
168
169 (defmethod database-store-next-row (result-set (database sqlite-database) list)
170   (let ((n-col (sqlite-result-set-n-col result-set))
171         (result-types (sqlite-result-set-result-types result-set)))
172     (if (= n-col 0)
173         ;; empty result set
174         nil
175         (let ((row (sqlite-result-set-first-row result-set)))
176           (if (sqlite:null-row-p row)
177               ;; First row already used. fetch another row from DB.
178               (handler-case
179                   (multiple-value-bind (n new-row col-names)
180                       (sqlite:sqlite-step (sqlite-result-set-vm result-set))
181                     (declare (ignore n col-names)
182                              #-clisp (type sqlite:sqlite-row-pointer-type new-row))
183                     (if (sqlite:null-row-p new-row)
184                         (return-from database-store-next-row nil)
185                         (setf row new-row)))
186                 (sqlite:sqlite-error (err)
187                   (error 'clsql-simple-error
188                          :format-control "Error in sqlite-step: ~A"
189                          :format-arguments
190                          (list (sqlite:sqlite-error-message err)))))
191
192               ;; Use the row previously read by database-query-result-set.
193               (setf (sqlite-result-set-first-row result-set)
194                     (sqlite:make-null-row)))
195           (loop for i = 0 then (1+ i)
196                 for rest on list
197                 do (setf (car rest)
198                          #-clisp
199                          (clsql-uffi:convert-raw-field
200                           (uffi:deref-array
201                            (uffi:deref-pointer row 'sqlite:sqlite-row-pointer) '(:array (* :unsigned-char)) i)
202                           result-types
203                           i)
204                          #+clisp
205                          (let ((type (if result-types
206                                          (nth i result-types)
207                                          :string))
208                                (val (sqlite:sqlite-aref row i)))
209                            (case type
210                              (:string
211                               val)
212                              (:integer
213                               (when val (parse-integer val)))
214                              (:number
215                               (read-from-string val))
216                              (:double
217                               (when val
218                                 (coerce
219                                  (read-from-string val)
220                                  'double-float)))))))
221           (sqlite:sqlite-free-row row)
222           t))))
223
224 ;;; Object listing
225
226 (defmethod database-list-tables ((database sqlite-database) &key owner)
227   (declare (ignore owner))
228   ;; Query is copied from .table command of sqlite comamnd line utility.
229   (remove-if #'(lambda (s)
230                  (and (>= (length s) 11)
231                       (string-equal (subseq s 0 11) "_CLSQL_SEQ_")))
232              (mapcar #'car (database-query
233                             "SELECT name FROM sqlite_master WHERE type='table' UNION ALL SELECT name FROM sqlite_temp_master WHERE type='table' ORDER BY name"
234                             database nil nil))))
235
236 (defmethod database-list-views ((database sqlite-database)
237                                 &key (owner nil))
238   (declare (ignore owner))
239   (mapcar #'car (database-query
240                  "SELECT name FROM sqlite_master WHERE type='view' UNION ALL SELECT name FROM sqlite_temp_master WHERE type='view' ORDER BY name"
241                  database nil nil)))
242
243 (defmethod database-list-indexes ((database sqlite-database)
244                                   &key (owner nil))
245   (declare (ignore owner))
246   (mapcar #'car (database-query
247                  "SELECT name FROM sqlite_master WHERE type='index' UNION ALL SELECT name FROM sqlite_temp_master WHERE type='index' ORDER BY name"
248                  database nil nil)))
249
250 (defmethod database-list-table-indexes (table (database sqlite-database)
251                                         &key (owner nil))
252   (declare (ignore owner))
253   (let ((*print-circle* nil))
254     (mapcar #'car 
255             (database-query
256              (format
257               nil
258               "SELECT name FROM sqlite_master WHERE type='index' AND tbl_name='~A' UNION ALL SELECT name FROM sqlite_temp_master WHERE type='index' AND tbl_name='~A' ORDER BY name"
259               table table)
260              database nil nil))))
261
262 (declaim (inline sqlite-table-info))
263 (defun sqlite-table-info (table database)
264   (database-query (format nil "PRAGMA table_info('~A')" table)
265                   database nil nil))
266
267 (defmethod database-list-attributes (table (database sqlite-database)
268                                            &key (owner nil))
269   (declare (ignore owner))
270   (mapcar #'(lambda (table-info) (second table-info))
271           (sqlite-table-info table database)))
272
273 (defmethod database-attribute-type (attribute table 
274                                     (database sqlite-database)
275                                     &key (owner nil))
276   (declare (ignore owner))
277   (loop for field-info in (sqlite-table-info table database)
278       when (string= attribute (second field-info))
279       return 
280         (let* ((raw-type (third field-info))
281                (start-length (position #\( raw-type))
282                (type (if start-length
283                          (subseq raw-type 0 start-length)
284                        raw-type))
285                (length (if start-length
286                            (parse-integer (subseq raw-type (1+ start-length))
287                                           :junk-allowed t)
288                          nil)))
289           (values (when type (ensure-keyword type)) 
290                   length
291                   nil
292                   (if (string-equal (fourth field-info) "0")
293                       1 0)))))
294
295 (defun %sequence-name-to-table-name (sequence-name)
296   (concatenate 'string "_CLSQL_SEQ_" (sql-escape sequence-name)))
297
298 (defun %table-name-to-sequence-name (table-name)
299   (and (>= (length table-name) 11)
300        (string= (subseq table-name 0 11) "_CLSQL_SEQ_")
301        (subseq table-name 11)))
302
303
304 (defmethod database-create-sequence (sequence-name
305                                      (database sqlite-database))
306   (let ((table-name (%sequence-name-to-table-name sequence-name)))
307     (database-execute-command
308      (concatenate 'string "CREATE TABLE " table-name
309                   " (last_value integer PRIMARY KEY, increment_by integer, min_value integer, is_called char(1))")
310      database)
311     (database-execute-command 
312      (concatenate 'string "INSERT INTO " table-name
313                   " VALUES (1,1,1,'f')")
314      database)))
315
316 (defmethod database-drop-sequence (sequence-name
317                                    (database sqlite-database))
318   (database-execute-command
319    (concatenate 'string "DROP TABLE " (%sequence-name-to-table-name sequence-name)) 
320    database))
321
322 (defmethod database-list-sequences ((database sqlite-database)
323                                     &key (owner nil))
324   (declare (ignore owner))
325   (mapcan #'(lambda (s)
326               (let ((sn (%table-name-to-sequence-name (car s))))
327                 (and sn (list sn))))
328           (database-query
329            "SELECT name FROM sqlite_master WHERE type='table' UNION ALL SELECT name FROM sqlite_temp_master WHERE type='table' ORDER BY name"
330            database nil nil)))
331
332 (defmethod database-sequence-next (sequence-name (database sqlite-database))
333   (without-interrupts
334    (let* ((table-name (%sequence-name-to-table-name sequence-name))
335           (tuple
336            (car (database-query 
337                  (concatenate 'string "SELECT last_value,is_called FROM " 
338                               table-name)
339                  database :auto nil))))
340      (cond
341        ((char-equal (schar (second tuple) 0) #\f)
342         (database-execute-command
343          (format nil "UPDATE ~A SET is_called='t'" table-name)
344          database)
345         (car tuple))
346        (t
347         (let ((new-pos (1+ (car tuple))))
348          (database-execute-command
349           (format nil "UPDATE ~A SET last_value=~D" table-name new-pos)
350           database)
351          new-pos))))))
352              
353 (defmethod database-sequence-last (sequence-name (database sqlite-database))
354   (without-interrupts
355    (caar (database-query 
356           (concatenate 'string "SELECT last_value FROM " 
357                        (%sequence-name-to-table-name sequence-name))
358             database :auto nil))))
359
360 (defmethod database-set-sequence-position (sequence-name
361                                            (position integer)
362                                            (database sqlite-database))
363   (database-execute-command
364    (format nil "UPDATE ~A SET last_value=~A,is_called='t'" 
365            (%sequence-name-to-table-name sequence-name)
366            position)
367    database)
368   position)
369
370 (defmethod database-create (connection-spec (type (eql :sqlite)))
371   (declare (ignore connection-spec))
372   ;; databases are created automatically by SQLite
373   t)
374
375 (defmethod database-destroy (connection-spec (type (eql :sqlite)))
376   (destructuring-bind (name) connection-spec
377     (if (probe-file name)
378         (delete-file name)
379         nil)))
380
381 (defmethod database-probe (connection-spec (type (eql :sqlite)))
382   (destructuring-bind (name) connection-spec
383     ;; TODO: Add a test that this file is a real sqlite database
384     (or (string-equal ":memory:" name)
385         (and (probe-file name) t))))
386
387 ;;; Database capabilities
388
389 (defmethod db-type-has-boolean-where? ((db-type (eql :sqlite)))
390   nil)
391
392
393