dbBind {DBI} | R Documentation |
For parametrized or prepared statements,
the dbSendQuery()
and dbSendStatement()
functions can be called with
statements that contain placeholders for values. The dbBind()
function
binds these placeholders
to actual values, and is intended to be called on the result set
before calling dbFetch()
or dbGetRowsAffected()
.
dbBind(res, params, ...)
res |
An object inheriting from DBIResult. |
params |
A list of bindings, named or unnamed. |
... |
Other arguments passed on to methods. |
DBI supports parametrized (or prepared) queries and statements
via the dbBind()
generic.
Parametrized queries are different from normal queries
in that they allow an arbitrary number of placeholders,
which are later substituted by actual values.
Parametrized queries (and statements) serve two purposes:
The same query can be executed more than once with different values. The DBMS may cache intermediate information for the query, such as the execution plan, and execute it faster.
Separation of query syntax and parameters protects against SQL injection.
The placeholder format is currently not specified by DBI;
in the future, a uniform placeholder syntax may be supported.
Consult the backend documentation for the supported formats.
For automated testing, backend authors specify the placeholder syntax with
the placeholder_pattern
tweak.
Known examples are:
?
(positional matching in order of appearance) in RMySQL and RSQLite
$1
(positional matching by index) in RPostgres and RSQLite
:name
and $name
(named matching) in RSQLite
dbBind()
returns the result set,
invisibly,
for queries issued by dbSendQuery()
and also for data manipulation statements issued by
dbSendStatement()
.
Calling dbBind()
for a query without parameters
raises an error.
Binding too many
or not enough values,
or parameters with wrong names
or unequal length,
also raises an error.
If the placeholders in the query are named,
all parameter values must have names
(which must not be empty
or NA
),
and vice versa,
otherwise an error is raised.
The behavior for mixing placeholders of different types
(in particular mixing positional and named placeholders)
is not specified.
Calling dbBind()
on a result set already cleared by dbClearResult()
also raises an error.
DBI clients execute parametrized statements as follows:
Call dbSendQuery()
or dbSendStatement()
with a query or statement
that contains placeholders,
store the returned DBIResult object in a variable.
Mixing placeholders (in particular, named and unnamed ones) is not
recommended.
It is good practice to register a call to dbClearResult()
via
on.exit()
right after calling dbSendQuery()
or dbSendStatement()
(see the last enumeration item).
Until dbBind()
has been called, the returned result set object has the
following behavior:
dbFetch()
raises an error (for dbSendQuery()
)
dbGetRowCount()
returns zero (for dbSendQuery()
)
dbGetRowsAffected()
returns an integer NA
(for dbSendStatement()
)
dbIsValid()
returns TRUE
dbHasCompleted()
returns FALSE
Construct a list with parameters
that specify actual values for the placeholders.
The list must be named or unnamed,
depending on the kind of placeholders used.
Named values are matched to named parameters, unnamed values
are matched by position in the list of parameters.
All elements in this list must have the same lengths and contain values
supported by the backend; a data.frame is internally stored as such
a list.
The parameter list is passed to a call to dbBind()
on the DBIResult
object.
Retrieve the data or the number of affected rows from the DBIResult
object.
For queries issued by dbSendQuery()
,
call dbFetch()
.
For statements issued by dbSendStatements()
,
call dbGetRowsAffected()
.
(Execution begins immediately after the dbBind()
call,
the statement is processed entirely before the function returns.)
Repeat 2. and 3. as necessary.
Close the result set via dbClearResult()
.
The elements of the params
argument do not need to be scalars,
vectors of arbitrary length
(including length 0)
are supported.
For queries, calling dbFetch()
binding such parameters returns
concatenated results, equivalent to binding and fetching for each set
of values and connecting via rbind()
.
For data manipulation statements, dbGetRowsAffected()
returns the
total number of rows affected if binding non-scalar parameters.
dbBind()
also accepts repeated calls on the same result set
for both queries
and data manipulation statements,
even if no results are fetched between calls to dbBind()
.
At least the following data types are accepted:
logical for Boolean values (some backends may return an integer)
factor (bound as character, with warning)
POSIXct timestamps
POSIXlt timestamps
lists of raw for blobs (with NULL
entries for SQL NULL values)
objects of type blob::blob
Other DBIResult generics: DBIResult-class
,
dbClearResult
, dbColumnInfo
,
dbFetch
, dbGetInfo
,
dbGetRowCount
,
dbGetRowsAffected
,
dbGetStatement
,
dbHasCompleted
, dbIsValid
,
dbQuoteIdentifier
,
dbQuoteString
con <- dbConnect(RSQLite::SQLite(), ":memory:") dbWriteTable(con, "iris", iris) # Using the same query for different values iris_result <- dbSendQuery(con, "SELECT * FROM iris WHERE [Petal.Width] > ?") dbBind(iris_result, list(2.3)) dbFetch(iris_result) dbBind(iris_result, list(3)) dbFetch(iris_result) dbClearResult(iris_result) # Executing the same statement with different values at once iris_result <- dbSendStatement(con, "DELETE FROM iris WHERE [Species] = $species") dbBind(iris_result, list(species = c("setosa", "versicolor", "unknown"))) dbGetRowsAffected(iris_result) dbClearResult(iris_result) nrow(dbReadTable(con, "iris")) dbDisconnect(con)