On this page:
3.1 Statements
statement?
3.2 Simple Queries
query-exec
query-rows
query-list
query-row
query-maybe-row
query-value
query-maybe-value
in-query
3.3 General Query Support
simple-result
rows-result
query
group-rows
rows->dict
3.4 Prepared Statements
prepare
prepared-statement?
prepared-statement-parameter-types
prepared-statement-result-types
bind-prepared-statement
statement-binding?
virtual-statement
virtual-statement?
3.5 Transactions
start-transaction
commit-transaction
rollback-transaction
in-transaction?
needs-rollback?
call-with-transaction
3.6 SQL Errors
exn:  fail:  sql
3.7 Database Catalog Information
list-tables
table-exists?
3.8 Creating New Kinds of Statements
prop:  statement
prop:  statement?

3 Queries🔗ℹ

This library provides a high-level functional query API, unlike many other database libraries, which present a stateful, iteration-based interface to queries. When a query function is invoked, it either returns a result or, if the query caused an error, raises an exception. Different query functions impose different constraints on the query results and offer different mechanisms for processing the results.

Errors  In most cases, a query error does not cause the connection to be disconnected. Specifically, the following kinds of errors should never cause a connection to be disconnected:
  • SQL syntax errors, such as references to undefined tables, columns, or operations, etc

  • SQL runtime errors, such as integrity constraint violations

  • violations of a specialized query function’s expectations, such as using query-value with a query that returns multiple columns

  • supplying the wrong number or wrong types of parameters to a prepared query, executing a prepared query with the wrong connection, etc

The following kinds of errors may cause a connection to be disconnected:
  • changing communication settings, such as changing the connection’s character encoding

  • communication failures and internal errors in the library

  • a break occurring during a connection operation

See Transactions for information on how errors can affect the transaction status.

Character encoding  This library is designed to interact with database systems using the UTF-8 character encoding. The connection functions attempt to negotiate UTF-8 communication at the beginning of every connection, but some systems also allow the character encoding to be changed via SQL commands (eg, SET NAMES). If this happens, the client might be unable to reliably communicate with the database, and data might get corrupted in transmission. Avoid changing a connection’s character encoding. When possible, the connection will observe the change and automatically disconnect with an error.

Synchronization  Connections are internally synchronized: it is safe to use a connection from different threads concurrently. Most connections are not kill-safe: killing a thread that is using a connection may leave the connection locked, causing future operations to block indefinitely. See also Kill-safe Connections.

3.1 Statements🔗ℹ

All query functions require both a connection and a statement, which is one of the following:

A SQL statement may contain parameter placeholders that stand for SQL scalar values; such statements are called parameterized queries. The parameter values must be supplied when the statement is executed; the parameterized statement and parameter values are sent to the database back end, which combines them correctly and safely.

Use parameters instead of Racket string operations (eg, format or string-append) to avoid SQL Injection.

The syntax of placeholders varies depending on the database system. For example:

PostgreSQL:

    

select * from the_numbers where n > $1;

MySQL, ODBC:

select * from the_numbers where n > ?;

SQLite:

supports both syntaxes (plus others)

procedure

(statement? x)  boolean?

  x : any/c
Returns #t if x is a statement, #f otherwise.

3.2 Simple Queries🔗ℹ

The simple query API consists of a set of functions specialized to various types of queries. For example, query-value is specialized to queries that return exactly one row of exactly one column.

If a statement takes parameters, the parameter values are given as additional arguments immediately after the SQL statement. Only a statement given as a string, prepared statement, or virtual statement can be given “inline” parameters; if the statement is a statement-binding, no inline parameters are permitted.

The types of parameters and returned fields are described in SQL Types and Conversions.

procedure

(query-exec connection stmt arg ...)  void?

  connection : connection?
  stmt : statement?
  arg : any/c
Executes a SQL statement for effect.

Examples:
> (query-exec pgc "insert into the_numbers values (42, 'the answer')")
> (query-exec pgc "delete from the_numbers where n = $1" 42)

procedure

(query-rows connection    
  stmt    
  arg ...    
  [#:group groupings    
  #:group-mode group-mode])  (listof vector?)
  connection : connection?
  stmt : statement?
  arg : any/c
  groupings : 
(let* ([field/c (or/c string? exact-nonnegative-integer?)]
       [grouping/c (or/c field/c (vectorof field/c))])
  (or/c grouping/c (listof grouping/c)))
   = null
  group-mode : (listof (or/c 'preserve-null 'list)) = null
Executes a SQL query, which must produce rows, and returns the list of rows (as vectors) from the query.

Examples:
> (query-rows pgc "select * from the_numbers where n = $1" 2)

'(#(2 "company"))

> (query-rows c "select 17")

'(#(17))

If groupings is not empty, the result is the same as if group-rows had been called on the result rows.

procedure

(query-list connection stmt arg ...)  list?

  connection : connection?
  stmt : statement?
  arg : any/c
Executes a SQL query, which must produce rows of exactly one column, and returns the list of values from the query.

Examples:
> (query-list c "select n from the_numbers where n < 2")

'(0 1)

> (query-list c "select 'hello'")

'("hello")

procedure

(query-row connection stmt arg ...)  vector?

  connection : connection?
  stmt : statement?
  arg : any/c
Executes a SQL query, which must produce exactly one row, and returns its (single) row result as a vector.

Examples:
> (query-row pgc "select * from the_numbers where n = $1" 2)

'#(2 "company")

> (query-row pgc "select min(n), max(n) from the_numbers")

'#(0 3)

procedure

(query-maybe-row connection stmt arg ...)  (or/c vector? #f)

  connection : connection?
  stmt : statement?
  arg : any/c
Like query-row, but the query may produce zero rows; in that case, #f is returned.

Examples:
> (query-maybe-row pgc "select * from the_numbers where n = $1" 100)

#f

> (query-maybe-row c "select 17")

'#(17)

procedure

(query-value connection stmt arg ...)  any/c

  connection : connection?
  stmt : statement?
  arg : any/c
Executes a SQL query, which must produce exactly one row of exactly one column, and returns its single value result.

Examples:
> (query-value pgc "select timestamp 'epoch'")

(sql-timestamp 1970 1 1 0 0 0 0 #f)

> (query-value pgc "select d from the_numbers where n = $1" 3)

"a crowd"

procedure

(query-maybe-value connection stmt arg ...)  (or/c any/c #f)

  connection : connection?
  stmt : statement?
  arg : any/c
Like query-value, but the query may produce zero rows; in that case, #f is returned.

Examples:
> (query-maybe-value pgc "select d from the_numbers where n = $1" 100)

#f

> (query-maybe-value c "select count(*) from the_numbers")

4

procedure

(in-query connection    
  stmt    
  arg ...    
  [#:fetch fetch-size    
  #:group groupings    
  #:group-mode group-mode])  sequence?
  connection : connection?
  stmt : statement?
  arg : any/c
  fetch-size : (or/c exact-positive-integer? +inf.0) = +inf.0
  groupings : 
(let* ([field/c (or/c string? exact-nonnegative-integer?)]
       [grouping/c (or/c field/c (vectorof field/c))])
  (or/c grouping/c (listof grouping/c)))
   = null
  group-mode : (listof (or/c 'preserve-null 'list)) = null
Executes a SQL query, which must produce rows, and returns a sequence. Each step in the sequence produces as many values as the rows have columns.

If fetch-size is +inf.0, all rows are fetched when the sequence is created. If fetch-size is finite, a cursor is created and fetch-size rows are fetched at a time, allowing processing to be interleaved with retrieval. On some database systems, ending a transaction implicitly closes all open cursors; attempting to fetch more rows may fail. On PostgreSQL, a cursor can be opened only within a transaction.

If groupings is not empty, the result is the same as if group-rows had been called on the result rows. If groupings is not empty, then fetch-size must be +inf.0; otherwise, an exception is raised.

Examples:
> (for/list ([n (in-query pgc "select n from the_numbers where n < 2")])
    n)

'(0 1)

> (call-with-transaction pgc
    (lambda ()
      (for ([(n d)
             (in-query pgc "select * from the_numbers where n < $1" 4
                       #:fetch 1)])
        (printf "~a: ~a\n" n d))))

0: nothing

1: the loneliest number

2: company

3: a crowd

An in-query application can provide better performance when it appears directly in a for clause. In addition, it may perform stricter checks on the number of columns returned by the query based on the number of variables in the clause’s left-hand side:

Example:
> (for ([n (in-query pgc "select * from the_numbers")])
    (displayln n))

in-query: query returned wrong number of columns

  statement: "select * from the_numbers"

  expected: 1

  got: 2

3.3 General Query Support🔗ℹ

A general query result is either a simple-result or a rows-result.

struct

(struct simple-result (info))

  info : (listof (cons/c symbol? any/c))
Represents the result of a SQL statement that does not return a relation, such as an INSERT or DELETE statement.

The info field is an association list, but its contents vary based on database system and may change in future versions of this library (even new minor versions). The following keys are supported for multiple database systems:

struct

(struct rows-result (headers rows))

  headers : (listof any/c)
  rows : (listof vector?)
Represents the result of SQL statement that results in a relation, such as a SELECT query.

The headers field is a list whose length is the number of columns in the result rows. Each header is usually an association list containing information about the column, but do not rely on its contents; it varies based on the database system and may change in future version of this library (even new minor versions).

procedure

(query connection stmt arg ...)

  (or/c simple-result? rows-result?)
  connection : connection?
  stmt : statement?
  arg : any/c
Executes a query, returning a structure that describes the results. Unlike the more specialized query functions, query supports both rows-returning and effect-only queries.

procedure

(group-rows result    
  #:group groupings    
  [#:group-mode group-mode])  rows-result?
  result : rows-result?
  groupings : 
(let* ([field/c (or/c string? exact-nonnegative-integer?)]
       [grouping/c (or/c field/c (vectorof field/c))])
  (or/c grouping/c (listof grouping/c)))
  group-mode : (listof (or/c 'preserve-null 'list)) = null
If groupings is a vector, the elements must be names of fields in result, and result’s rows are regrouped using the given fields. Each grouped row contains N+1 fields; the first N fields are the groupings, and the final field is a list of “residual rows” over the rest of the fields. A residual row of all NULLs is dropped (for convenient processing of OUTER JOIN results) unless group-mode includes 'preserve-null. If group-mode contains 'list, there must be exactly one residual field, and its values are included without a vector wrapper (similar to query-list).

See also The N+1 Selects Problem.

Examples:
> (define vehicles-result
    (rows-result
     '(((name . "type")) ((name . "maker")) ((name . "model")))
     `(#("car"  "honda"   "civic")
       #("car"  "ford"    "focus")
       #("car"  "ford"    "pinto")
       #("bike" "giant"   "boulder")
       #("bike" "schwinn" ,sql-null))))
> (group-rows vehicles-result
              #:group '(#("type")))

(rows-result

 '(((name . "type"))

   ((name . "grouped") (grouped ((name . "maker")) ((name . "model")))))

 '(#("car" (#("honda" "civic") #("ford" "focus") #("ford" "pinto")))

   #("bike" (#("giant" "boulder") #("schwinn" #<sql-null>)))))

The grouped final column is given the name "grouped".

The groupings argument may also be a list of vectors; in that case, the grouping process is repeated for each set of grouping fields. The grouping fields must be distinct.

Example:
> (group-rows vehicles-result
              #:group '(#("type") #("maker"))
              #:group-mode '(list))

(rows-result

 '(((name . "type"))

   ((name . "grouped")

    (grouped

     ((name . "maker"))

     ((name . "grouped") (grouped ((name . "model")))))))

 '(#("car" (#("honda" ("civic")) #("ford" ("focus" "pinto"))))

   #("bike" (#("giant" ("boulder")) #("schwinn" ())))))

procedure

(rows->dict result    
  #:key key-field/s    
  #:value value-field/s    
  [#:value-mode value-mode])  dict?
  result : rows-result?
  key-field/s : 
(let ([field/c (or/c string? exact-nonnegative-integer?)])
  (or/c field/c (vectorof field/c)))
  value-field/s : 
(let ([field/c (or/c string? exact-nonnegative-integer?)])
  (or/c field/c (vectorof field/c)))
  value-mode : (listof (or/c 'list 'preserve-null)) = null
Creates a dictionary mapping key-field/s to value-field/s. If key-field/s is a single field name or index, the keys are the field values; if key-field/s is a vector, the keys are vectors of the field values. Likewise for value-field/s.

If value-mode contains 'list, a list of values is accumulated for each key; otherwise, there must be at most one value for each key. Values consisting of all sql-null? values are dropped unless value-mode contains 'preserve-null.

Examples:
> (rows->dict vehicles-result
              #:key "model" #:value '#("type" "maker"))

'#hash(("focus" . #("car" "ford"))

       ("civic" . #("car" "honda"))

       (#<sql-null> . #("bike" "schwinn"))

       ("boulder" . #("bike" "giant"))

       ("pinto" . #("car" "ford")))

> (rows->dict vehicles-result
              #:key "maker" #:value "model" #:value-mode '(list))

'#hash(("ford" . ("focus" "pinto"))

       ("giant" . ("boulder"))

       ("honda" . ("civic"))

       ("schwinn" . ()))

3.4 Prepared Statements🔗ℹ

A prepared statement is the result of a call to prepare.

Any server-side or native-library resources associated with a prepared statement are released when the prepared statement is garbage-collected or when the connection that owns it is closed; prepared statements do not need to be (and cannot be) explicitly closed.

procedure

(prepare connection stmt)  prepared-statement?

  connection : connection?
  stmt : (or/c string? virtual-statement?)
Prepares a statement. The resulting prepared statement is tied to the connection that prepared it; attempting to execute it with another connection will trigger an exception. The prepared statement holds its connection link weakly; a reference to a prepared statement will not keep a connection from being garbage collected.

Changed in version 1.10 of package db-lib: Changed to accept virtual statements in addition to strings.

procedure

(prepared-statement? x)  boolean?

  x : any/c
Returns #t if x is a prepared statement created by prepare, #f otherwise.

Returns a list with one element for each of the prepared statement’s parameters. Each element is itself a list of the following form:

(list supported? type typeid)

The supported? field indicates whether the type is supported by this library; the type field is a symbol corresponding to an entry in one of the tables in SQL Type Conversions; and the typeid field is a system-specific type identifier. The type description list format may be extended with additional information in future versions of this library.

If pst is a rows-returning statement (eg, SELECT), returns a list of type descriptions as described above, identifying the SQL types (or pseudo-types) of the result columns. If pst is not a rows-returning statement, the function returns the empty list.

procedure

(bind-prepared-statement pst params)  statement-binding?

  pst : prepared-statement?
  params : (listof any/c)
Creates a statement-binding value pairing pst with params, a list of parameter arguments. The result can be executed with query or any of the other query functions, but it must be used with the same connection that created pst.

Example:
> (let* ([get-name-pst
          (prepare pgc "select d from the_numbers where n = $1")]
         [get-name2
          (bind-prepared-statement get-name-pst (list 2))]
         [get-name3
          (bind-prepared-statement get-name-pst (list 3))])
    (list (query-value pgc get-name2)
          (query-value pgc get-name3)))

'("company" "a crowd")

Most query functions perform the binding step implicitly.

procedure

(statement-binding? x)  boolean?

  x : any/c
Returns #t if x is a statement created by bind-prepared-statement, #f otherwise.

procedure

(virtual-statement gen)  virtual-statement?

  gen : (or/c string? (-> dbsystem? string?))
Creates a virtual statement, stmt, which encapsulates a weak mapping of connections to prepared statements. When a query function is called with stmt and a connection, the weak hash is consulted to see if the statement has already been prepared for that connection. If so, the prepared statement is used; otherwise, the statement is prepared and stored in the table.

The gen argument must be either a SQL string or a function that accepts a database system object and produces a SQL string. The function variant allows the SQL syntax to be dynamically customized for the database system in use.

Examples:
> (define pst
    (virtual-statement
     (lambda (dbsys)
       (case (dbsystem-name dbsys)
         ((postgresql) "select n from the_numbers where n < $1")
         ((sqlite3) "select n from the_numbers where n < ?")
         (else (error "unknown system"))))))
> (query-list pgc pst 3)

'(0 1 2)

> (query-list slc pst 3)

'(0 1 2)

procedure

(virtual-statement? x)  boolean?

  x : any/c
Returns #t if x is a virtual statement created by virtual-statement, #f otherwise.

3.5 Transactions🔗ℹ

The functions described in this section provide a consistent interface to transactions.

A managed transaction is one created via either start-transaction or call-with-transaction. In contrast, an unmanaged transaction is one created by evaluating a SQL statement such as START TRANSACTION. A nested transaction is a transaction created within the extent of an existing transaction. If a nested transaction is committed, its changes are promoted to the enclosing transaction, which may itself be committed or rolled back. If a nested transaction is rolled back, its changes are discarded, but the enclosing transaction remains open. Nested transactions are implemented via SQL SAVEPOINT, RELEASE SAVEPOINT, and ROLLBACK TO SAVEPOINT.

ODBC connections must use managed transactions exclusively; using transaction-changing SQL may cause these functions to behave incorrectly and may cause additional problems in the ODBC driver. ODBC connections do not support nested transactions.

PostgreSQL, MySQL, and SQLite connections must not mix managed and unmanaged transactions. For example, calling start-transaction and then executing a ROLLBACK statement is not allowed. Note that in MySQL, some SQL statements have implicit transaction effects. For example, in MySQL a CREATE TABLE statement implicitly commits the current transaction. These statements also must not be used within managed transactions. (In contrast, PostgreSQL and SQLite both support transactional DDL.)

Errors  Query errors may affect an open transaction in one of three ways:
  1. the transaction remains open and unchanged

  2. the transaction is automatically rolled back

  3. the transaction becomes an invalid transaction; all subsequent queries will fail until the transaction is rolled back

To avoid the silent loss of information, this library attempts to avoid behavior (2) completely by marking transactions as invalid instead (3). Invalid transactions can be identified using the needs-rollback? function. The following list is a rough guide to what errors cause which behaviors:
  • All errors raised by checks performed by this library, such as parameter arity and type errors, leave the transaction open and unchanged (1).

  • All errors originating from PostgreSQL cause the transaction to become invalid (3).

  • Most errors originating from MySQL leave the transaction open and unchanged (1), but a few cause the transaction to become invalid (3). In the latter cases, the underlying behavior of MySQL is to roll back the transaction but leave it open (see the MySQL documentation). This library detects those cases and marks the transaction invalid instead.

  • Most errors originating from SQLite leave the transaction open and unchanged (1), but a few cause the transaction to become invalid (3). In the latter cases, the underlying behavior of SQLite is to roll back the transaction (see the SQLite documentation). This library detects those cases and marks the transaction invalid instead.

  • All errors originating from an ODBC driver cause the transaction to become invalid (3). The underlying behavior of ODBC drivers varies widely, and ODBC provides no mechanism to detect when an existing transaction has been rolled back, so this library intercepts all errors and marks the transaction invalid instead.

If a nested transaction marked invalid is rolled back, the enclosing transaction is typically still valid.

If a transaction is open when a connection is disconnected, it is implicitly rolled back.

procedure

(start-transaction c    
  [#:isolation isolation-level    
  #:option option])  void?
  c : connection?
  isolation-level : 
(or/c 'serializable
      'repeatable-read
      'read-committed
      'read-uncommitted
      #f)
 = #f
  option : any/c = #f
Starts a transaction with isolation isolation-level. If isolation-level is #f, the isolation is database-dependent; it may be a default isolation level or it may be the isolation level of the previous transaction.

The behavior of option depends on the database system:
If option is not supported, an exception is raised.

If c is already in a transaction, isolation-level and option must both be #f, and a nested transaction is opened.

See also Transactions and Concurrency.

procedure

(commit-transaction c)  void?

  c : connection?
Attempts to commit the current transaction, if one is open. If the transaction cannot be committed (for example, if it is invalid), an exception is raised.

If the current transaction is a nested transaction, the nested transaction is closed, its changes are incorporated into the enclosing transaction, and the enclosing transaction is resumed.

If no transaction is open, this function has no effect.

procedure

(rollback-transaction c)  void?

  c : connection?
Rolls back the current transaction, if one is open.

If the current transaction is a nested transaction, the nested transaction is closed, its changes are abandoned, and the enclosing transaction is resumed.

If no transaction is open, this function has no effect.

procedure

(in-transaction? c)  boolean?

  c : connection?
Returns #t if c has an open transaction (managed or unmanaged), #f otherwise.

procedure

(needs-rollback? c)  boolean?

  c : connection?
Returns #t if c is in an invalid transaction. All queries executed using c will fail until the transaction is rolled back (either using rollback-transaction, if the transaction was created with start-transaction, or when the procedure passed to call-with-transaction returns).

procedure

(call-with-transaction c    
  proc    
  [#:isolation isolation-level    
  #:option option])  any
  c : connection?
  proc : (-> any)
  isolation-level : 
(or/c 'serializable
      'repeatable-read
      'read-committed
      'read-uncommitted
      #f)
 = #f
  option : any/c = #f
Calls proc in the context of a new transaction with isolation level isolation-level. If proc completes normally, the transaction is committed and proc’s results are returned. If proc raises an exception (or if the implicit commit at the end raises an exception), the transaction is rolled back and the exception is re-raised.

If call-with-transaction is called within a transaction, isolation-level must be #f, and it creates a nested transaction. Within the extent of a call to call-with-transaction, transactions must be properly nested. In particular:

3.6 SQL Errors🔗ℹ

SQL errors are represented by the exn:fail:sql exception type.

struct

(struct exn:fail:sql exn:fail (sqlstate info)
    #:extra-constructor-name make-exn:fail:sql)
  sqlstate : (or/c string? symbol?)
  info : (listof (cons/c symbol? any/c))
Represents a SQL error originating from the database server or native library. The sqlstate field contains the SQLSTATE code (a five-character string) of the error for PostgreSQL, MySQL, or ODBC connections or a symbol for SQLite connections. Refer to the database system’s documentation for the definitions of error codes:

The info field contains all information available about the error as an association list. The available keys vary, but the 'message key is typically present; its value is a string containing the error message.

Example:
> (with-handlers ([exn:fail:sql? exn:fail:sql-info])
    (query pgc "select * from nosuchtable"))

'((severity . "ERROR")

  (severity* . "ERROR")

  (code . "42P01")

  (message . "relation \"nosuchtable\" does not exist")

  (position . "15")

  (file . "parse_relation.c")

  (line . "1194")

  (routine . "parserOpenTable"))

Errors originating from the db library, such as arity and contract errors, type conversion errors, etc, are not represented by exn:fail:sql.

3.7 Database Catalog Information🔗ℹ

procedure

(list-tables c [#:schema schema])  (listof string?)

  c : connection?
  schema : (or/c 'search-or-current 'search 'current)
   = 'search-or-current
Returns a list of unqualified names of tables (and views) defined in the current database.

If schema is 'search, the list contains all tables in the current schema search path (with the possible exception of system tables); if the search path cannot be determined, an exception is raised. If schema is 'current, the list contains all tables in the current schema. If schema is 'search-or-current (the default), the search path is used if it can be determined; otherwise the current schema is used. The schema search path cannot be determined for ODBC-based connections.

procedure

(table-exists? c    
  table-name    
  [#:schema schema    
  #:case-sensitive? case-sensitive?])  boolean?
  c : connection?
  table-name : string?
  schema : (or/c 'search-or-current 'search 'current)
   = 'search-or-current
  case-sensitive? : any/c = #f
Indicates whether a table (or view) named table-name exists. The meaning of the schema argument is the same as for list-tables, and the case-sensitive? argument controls how table names are compared.

3.8 Creating New Kinds of Statements🔗ℹ

A struct type property for creating new kinds of statements. The property value is applied to the struct instance and a connection, and it must return a statement.

procedure

(prop:statement? v)  boolean?

  v : any/c
Returns #t if v is an instance of a struct implementing prop:statement, #f otherwise.

Added in version 1.5 of package db-lib.