1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 46 47 48 49 50 51 52 53 54 55 56 57 58 59 60 61 62 63 64 65 66 67 68 69 70 71 72 73 74 75 76 77 78 79 80 81 82 83 84 85 86 87 88 89 90 91 92 93 94 95 96 97 98 99 100 101 102 103 104 105 106 107 108 109 110 111 112 113 114 115 116 117 118 119 120 121 122 123 124 125 126 127 128 129 130 131 132 133 134 135 136 137 138 139 140 141 142 143 144 145 146 147 148 149 150 151 152 153 154 155 156 157 158 159 160 161 162 163 164 165 166 167 168 169 170 171 172 173 174 175 176 177 178 179 180 181 182 183 184 185 186 187 188 189 190 191 192 193 194 195 196 197 198 199 200 201 202 203 204 205 206 207 208 209 210 211 212 213 214 215 216 217 218 219 220 221 222 223 224 225 226 227 228 229 230 231 232 233 234 235 236 237 238 239 240 241 242 243 244 245 246 247 248 249 250 251 252 253 254 255 256 257 258 259 260 261 262 263 264 265 266 267 268 269 270 271 272 273 274 275 276 277 278 279 280 281 282 283 284 285 286 287 288 289 290 291 292 293 294 295 296 297 298 299 300 301 302 303 304 305 306 307 308 309 310 311 312 313 314 315 316 317 318 319 320 321 322 323 324 325 326 327 328 329 330 331 332 333 334 335 336 337 338 339 340 341 342 343 344 345 346 347 348 349 350 351 352 353 354 355 356 357 358 359 360 361 362 363 364 365 366 367 368 369 370 371 372 373 374 375 376 377 378 379 380 381 382 383 384 385
|
% Generated by roxygen2: do not edit by hand
% Please edit documentation in R/15-dbBind.R, R/25-dbBindArrow.R
\name{dbBind}
\alias{dbBind}
\alias{dbBindArrow}
\title{Bind values to a parameterized/prepared statement}
\usage{
dbBind(res, params, ...)
dbBindArrow(res, params, ...)
}
\arguments{
\item{res}{An object inheriting from \linkS4class{DBIResult}.}
\item{params}{For \code{dbBind()}, a list of values, named or unnamed,
or a data frame, with one element/column per query parameter.
For \code{dbBindArrow()}, values as a nanoarrow stream,
with one column per query parameter.}
\item{...}{Other arguments passed on to methods.}
}
\value{
\code{dbBind()} returns the result set,
invisibly,
for queries issued by \code{\link[=dbSendQuery]{dbSendQuery()}} or \code{\link[=dbSendQueryArrow]{dbSendQueryArrow()}} and
also for data manipulation statements issued by
\code{\link[=dbSendStatement]{dbSendStatement()}}.
}
\description{
For parametrized or prepared statements,
the \code{\link[=dbSendQuery]{dbSendQuery()}}, \code{\link[=dbSendQueryArrow]{dbSendQueryArrow()}}, and \code{\link[=dbSendStatement]{dbSendStatement()}} functions
can be called with statements that contain placeholders for values.
The \code{dbBind()} and \code{dbBindArrow()} functions bind these placeholders
to actual values,
and are intended to be called on the result set
before calling \code{\link[=dbFetch]{dbFetch()}} or \code{\link[=dbFetchArrow]{dbFetchArrow()}}.
The values are passed to \code{dbBind()} as lists or data frames,
and to \code{dbBindArrow()} as a stream
created by \code{\link[nanoarrow:as_nanoarrow_array_stream]{nanoarrow::as_nanoarrow_array_stream()}}.
\ifelse{html}{\href{https://lifecycle.r-lib.org/articles/stages.html#experimental}{\figure{lifecycle-experimental.svg}{options: alt='[Experimental]'}}}{\strong{[Experimental]}}
\code{dbBindArrow()} is experimental, as are the other \verb{*Arrow} functions.
\code{dbSendQuery()} is compatible with \code{dbBindArrow()}, and \code{dbSendQueryArrow()}
is compatible with \code{dbBind()}.
\Sexpr[results=rd,stage=render]{DBI:::methods_as_rd("dbBind")}
}
\details{
\pkg{DBI} supports parametrized (or prepared) queries and statements
via the \code{dbBind()} and \code{dbBindArrow()} generics.
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:
\itemize{
\item 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.
\item Separation of query syntax and parameters protects against SQL injection.
}
The placeholder format is currently not specified by \pkg{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 \code{placeholder_pattern} tweak.
Known examples are:
\itemize{
\item \verb{?} (positional matching in order of appearance) in \pkg{RMariaDB} and \pkg{RSQLite}
\item \verb{$1} (positional matching by index) in \pkg{RPostgres} and \pkg{RSQLite}
\item \verb{:name} and \verb{$name} (named matching) in \pkg{RSQLite}
}
}
\section{The data retrieval flow}{
This section gives a complete overview over the flow
for the execution of queries that return tabular data as data frames.
Most of this flow, except repeated calling of \code{\link[=dbBind]{dbBind()}} or \code{\link[=dbBindArrow]{dbBindArrow()}},
is implemented by \code{\link[=dbGetQuery]{dbGetQuery()}}, which should be sufficient
unless you want to access the results in a paged way
or you have a parameterized query that you want to reuse.
This flow requires an active connection established by \code{\link[=dbConnect]{dbConnect()}}.
See also \code{vignette("dbi-advanced")} for a walkthrough.
\enumerate{
\item Use \code{\link[=dbSendQuery]{dbSendQuery()}} to create a result set object of class
\linkS4class{DBIResult}.
\item Optionally, bind query parameters with \code{\link[=dbBind]{dbBind()}} or \code{\link[=dbBindArrow]{dbBindArrow()}}.
This is required only if the query contains placeholders
such as \verb{?} or \verb{$1}, depending on the database backend.
\item Optionally, use \code{\link[=dbColumnInfo]{dbColumnInfo()}} to retrieve the structure of the result set
without retrieving actual data.
\item Use \code{\link[=dbFetch]{dbFetch()}} to get the entire result set, a page of results,
or the remaining rows.
Fetching zero rows is also possible to retrieve the structure of the result set
as a data frame.
This step can be called multiple times.
Only forward paging is supported, you need to cache previous pages
if you need to navigate backwards.
\item Use \code{\link[=dbHasCompleted]{dbHasCompleted()}} to tell when you're done.
This method returns \code{TRUE} if no more rows are available for fetching.
\item Repeat the last four steps as necessary.
\item Use \code{\link[=dbClearResult]{dbClearResult()}} to clean up the result set object.
This step is mandatory even if no rows have been fetched
or if an error has occurred during the processing.
It is good practice to use \code{\link[=on.exit]{on.exit()}} or \code{\link[withr:defer]{withr::defer()}}
to ensure that this step is always executed.
}
}
\section{The data retrieval flow for Arrow streams}{
This section gives a complete overview over the flow
for the execution of queries that return tabular data as an Arrow stream.
Most of this flow, except repeated calling of \code{\link[=dbBindArrow]{dbBindArrow()}} or \code{\link[=dbBind]{dbBind()}},
is implemented by \code{\link[=dbGetQueryArrow]{dbGetQueryArrow()}},
which should be sufficient
unless you have a parameterized query that you want to reuse.
This flow requires an active connection established by \code{\link[=dbConnect]{dbConnect()}}.
See also \code{vignette("dbi-advanced")} for a walkthrough.
\enumerate{
\item Use \code{\link[=dbSendQueryArrow]{dbSendQueryArrow()}} to create a result set object of class
\linkS4class{DBIResultArrow}.
\item Optionally, bind query parameters with \code{\link[=dbBindArrow]{dbBindArrow()}} or \code{\link[=dbBind]{dbBind()}}.
This is required only if the query contains placeholders
such as \verb{?} or \verb{$1}, depending on the database backend.
\item Use \code{\link[=dbFetchArrow]{dbFetchArrow()}} to get a data stream.
\item Repeat the last two steps as necessary.
\item Use \code{\link[=dbClearResult]{dbClearResult()}} to clean up the result set object.
This step is mandatory even if no rows have been fetched
or if an error has occurred during the processing.
It is good practice to use \code{\link[=on.exit]{on.exit()}} or \code{\link[withr:defer]{withr::defer()}}
to ensure that this step is always executed.
}
}
\section{The command execution flow}{
This section gives a complete overview over the flow
for the execution of SQL statements that have side effects
such as stored procedures, inserting or deleting data,
or setting database or connection options.
Most of this flow, except repeated calling of \code{\link[=dbBindArrow]{dbBindArrow()}},
is implemented by \code{\link[=dbExecute]{dbExecute()}}, which should be sufficient
for non-parameterized queries.
This flow requires an active connection established by \code{\link[=dbConnect]{dbConnect()}}.
See also \code{vignette("dbi-advanced")} for a walkthrough.
\enumerate{
\item Use \code{\link[=dbSendStatement]{dbSendStatement()}} to create a result set object of class
\linkS4class{DBIResult}.
For some queries you need to pass \code{immediate = TRUE}.
\item Optionally, bind query parameters with\code{\link[=dbBind]{dbBind()}} or \code{\link[=dbBindArrow]{dbBindArrow()}}.
This is required only if the query contains placeholders
such as \verb{?} or \verb{$1}, depending on the database backend.
\item Optionally, use \code{\link[=dbGetRowsAffected]{dbGetRowsAffected()}} to retrieve the number
of rows affected by the query.
\item Repeat the last two steps as necessary.
\item Use \code{\link[=dbClearResult]{dbClearResult()}} to clean up the result set object.
This step is mandatory even if no rows have been fetched
or if an error has occurred during the processing.
It is good practice to use \code{\link[=on.exit]{on.exit()}} or \code{\link[withr:defer]{withr::defer()}}
to ensure that this step is always executed.
}
}
\section{Failure modes}{
Calling \code{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 \code{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 \code{dbBind()} on a result set already cleared by \code{\link[=dbClearResult]{dbClearResult()}}
also raises an error.
}
\section{Specification}{
\pkg{DBI} clients execute parametrized statements as follows:
\enumerate{
\item Call \code{\link[=dbSendQuery]{dbSendQuery()}}, \code{\link[=dbSendQueryArrow]{dbSendQueryArrow()}} or \code{\link[=dbSendStatement]{dbSendStatement()}}
with a query or statement that contains placeholders,
store the returned \linkS4class{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 \code{\link[=dbClearResult]{dbClearResult()}} via
\code{\link[=on.exit]{on.exit()}} right after calling \code{dbSendQuery()} or \code{dbSendStatement()}
(see the last enumeration item).
Until \code{\link[=dbBind]{dbBind()}} or \code{\link[=dbBindArrow]{dbBindArrow()}} have been called,
the returned result set object has the following behavior:
\itemize{
\item \code{\link[=dbFetch]{dbFetch()}} raises an error (for \code{dbSendQuery()} and \code{dbSendQueryArrow()})
\item \code{\link[=dbGetRowCount]{dbGetRowCount()}} returns zero (for \code{dbSendQuery()} and \code{dbSendQueryArrow()})
\item \code{\link[=dbGetRowsAffected]{dbGetRowsAffected()}} returns an integer \code{NA} (for \code{dbSendStatement()})
\item \code{\link[=dbIsValid]{dbIsValid()}} returns \code{TRUE}
\item \code{\link[=dbHasCompleted]{dbHasCompleted()}} returns \code{FALSE}
}
\item Call \code{\link[=dbBind]{dbBind()}} or \code{\link[=dbBindArrow]{dbBindArrow()}}:
\itemize{
\item For \code{\link[=dbBind]{dbBind()}}, the \code{params} argument must be a list where all elements
have the same lengths and contain values supported by the backend.
A \link{data.frame} is internally stored as such a list.
\item For \code{\link[=dbBindArrow]{dbBindArrow()}}, the \code{params} argument must be a
nanoarrow array stream, with one column per query parameter.
}
\item Retrieve the data or the number of affected rows from the \code{DBIResult} object.
\itemize{
\item For queries issued by \code{dbSendQuery()} or \code{dbSendQueryArrow()}, call \code{\link[=dbFetch]{dbFetch()}}.
\item For statements issued by \code{dbSendStatements()},
call \code{\link[=dbGetRowsAffected]{dbGetRowsAffected()}}.
(Execution begins immediately after the \code{\link[=dbBind]{dbBind()}} call,
the statement is processed entirely before the function returns.)
}
\item Repeat 2. and 3. as necessary.
\item Close the result set via \code{\link[=dbClearResult]{dbClearResult()}}.
}
The elements of the \code{params} argument do not need to be scalars,
vectors of arbitrary length
(including length 0)
are supported.
For queries, calling \code{dbFetch()} binding such parameters returns
concatenated results, equivalent to binding and fetching for each set
of values and connecting via \code{\link[=rbind]{rbind()}}.
For data manipulation statements, \code{dbGetRowsAffected()} returns the
total number of rows affected if binding non-scalar parameters.
\code{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 \code{dbBind()},
for both queries
and data manipulation statements.
If the placeholders in the query are named,
their order in the \code{params} argument is not important.
At least the following data types are accepted on input (including \link{NA}):
\itemize{
\item \link{integer}
\item \link{numeric}
\item \link{logical} for Boolean values
\item \link{character}
(also with special characters such as spaces, newlines, quotes, and backslashes)
\item \link{factor} (bound as character,
with warning)
\item \link{Date}
(also when stored internally as integer)
\item \link{POSIXct} timestamps
\item \link{POSIXlt} timestamps
\item \link{difftime} values
(also with units other than seconds
and with the value stored as integer)
\item lists of \link{raw} for blobs (with \code{NULL} entries for SQL NULL values)
\item objects of type \link[blob:blob]{blob::blob}
}
}
\examples{
\dontshow{if (requireNamespace("RSQLite", quietly = TRUE)) (if (getRversion() >= "3.4") withAutoprint else force)(\{ # examplesIf}
# Data frame flow:
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)
\dontshow{\}) # examplesIf}
\dontshow{if (requireNamespace("RSQLite", quietly = TRUE) && requireNamespace("nanoarrow", quietly = TRUE)) (if (getRversion() >= "3.4") withAutoprint else force)(\{ # examplesIf}
# Arrow flow:
con <- dbConnect(RSQLite::SQLite(), ":memory:")
dbWriteTable(con, "iris", iris)
# Using the same query for different values
iris_result <- dbSendQueryArrow(con, "SELECT * FROM iris WHERE [Petal.Width] > ?")
dbBindArrow(
iris_result,
nanoarrow::as_nanoarrow_array_stream(data.frame(2.3, fix.empty.names = FALSE))
)
as.data.frame(dbFetchArrow(iris_result))
dbBindArrow(
iris_result,
nanoarrow::as_nanoarrow_array_stream(data.frame(3, fix.empty.names = FALSE))
)
as.data.frame(dbFetchArrow(iris_result))
dbClearResult(iris_result)
# Executing the same statement with different values at once
iris_result <- dbSendStatement(con, "DELETE FROM iris WHERE [Species] = $species")
dbBindArrow(iris_result, nanoarrow::as_nanoarrow_array_stream(data.frame(
species = c("setosa", "versicolor", "unknown")
)))
dbGetRowsAffected(iris_result)
dbClearResult(iris_result)
nrow(dbReadTable(con, "iris"))
dbDisconnect(con)
\dontshow{\}) # examplesIf}
}
\seealso{
Other DBIResult generics:
\code{\link{DBIResult-class}},
\code{\link{dbClearResult}()},
\code{\link{dbColumnInfo}()},
\code{\link{dbFetch}()},
\code{\link{dbGetInfo}()},
\code{\link{dbGetRowCount}()},
\code{\link{dbGetRowsAffected}()},
\code{\link{dbGetStatement}()},
\code{\link{dbHasCompleted}()},
\code{\link{dbIsReadOnly}()},
\code{\link{dbIsValid}()},
\code{\link{dbQuoteLiteral}()},
\code{\link{dbQuoteString}()}
Other DBIResultArrow generics:
\code{\link{DBIResultArrow-class}},
\code{\link{dbClearResult}()},
\code{\link{dbFetchArrow}()},
\code{\link{dbFetchArrowChunk}()},
\code{\link{dbHasCompleted}()},
\code{\link{dbIsValid}()}
Other data retrieval generics:
\code{\link{dbClearResult}()},
\code{\link{dbFetch}()},
\code{\link{dbFetchArrow}()},
\code{\link{dbFetchArrowChunk}()},
\code{\link{dbGetQuery}()},
\code{\link{dbGetQueryArrow}()},
\code{\link{dbHasCompleted}()},
\code{\link{dbSendQuery}()},
\code{\link{dbSendQueryArrow}()}
Other command execution generics:
\code{\link{dbClearResult}()},
\code{\link{dbExecute}()},
\code{\link{dbGetRowsAffected}()},
\code{\link{dbSendStatement}()}
}
\concept{DBIResult generics}
\concept{DBIResultArrow generics}
\concept{command execution generics}
\concept{data retrieval generics}
|