Parameterized SQL queries

The package RODBCext is an extension of the RODBC database connectivity package. It provides support for parameterized queries. This document describes what parameterized queries are and when they should be used. In addition some examples of ROBDCext usage are shown.

It is assumed that you already know the RODBC package and the basics of SQL and ODBC. If not, please read about them first, e.g. see the ODBC Connectivity vignette of the RODBC package.

What are parameterized queries for?

Parameterized queries (also known as prepared statements) are a technique of query execution which separates a query string from query parameters values. There are two main reasons for using this technique:

Both are discussed below.

SQL injections

SQL injection is an attack against your code which uses SQL queries. Malicious query parameter values are passed in order to modify and execute a query. If you use SQL data sources, it is highly likely that sooner or later your R code will experience a problem similar to an SQL injection (or an SQL injection itself). Consider the following:

Example - an apostrophe sign in data

Let us begin with a simple example illustrating how your own data can lead to problems similar to a SQL injections attack.

Imagine a simple SQL database with a table called cakes:

cake | price --------------------|-------- Chocolate cake | 10 Strawberry cupcake | 3 Kevin's Cherry Tart | 12.3 ... | ...

We receive a CSV data file containing the same database but with new prices. You are asked to update the database. So you write your R code as below:

library(RODBC)

connHandle <- odbcConnect("cakesDatabase")
newData <- read.csv("newData.csv", stringsAsFactors = F)

for(row in seq_len(nrow(newData))){
  query <- paste0(
    "UPDATE cakes 
     SET price = ", newData$price[row], " 
     WHERE cake = '", newData$cake[row], "'"
  )
  sqlQuery(connHandle, query)
}

odbcClose(connHandle)

Such a code will fail on a Kevin's Cherry Tart because this name contains an apostrophe. The resulting query would be UPDATE cakes SET price = 12.3 WHERE cake = 'Kevin's Cherry Tart'; which is not a proper SQL query. To deal with the Kevin's Cherry Tart we need to escape the apostrophe in the cake's name so that the database knows that it doesn't denote the end of the string value.

Example - simple SQL injection

There is a nice XKCD about that - see here. Let's translate it into an example in R.

We have got a database of students with a table students

last_name | first_name ----------|----------- Smith | John Lee | Andrew Wilson | Linda ... | ...

A new school year has begun and new students have come. We have just received a CSV file with the same structure as the table students and we are asked to add it to the database. So we prepare a simple script:

library(RODBC)

connHandle <- odbcConnect('studentsDatabase')
newStudents <- read.csv('newStudents.csv', stringsAsFactors = F)

for(row in seq_len(nrow(newStudents))){
  query <- paste0(
    "INSERT INTO students (first_name, last_name)
     VALUES (
       '", newStudents$first_name[row],"', 
       '", newStudents$last_name[row],"', 
     )"
  )
  sqlQuery(connHandle, query)
}

odbcClose(connHandle)

Unfortunately one of our new students' name is:

last_name | first_name ----------|---------------------------------- Smith | Robert'); DROP TABLE students; --

For this student our query would be:

INSERT INTO students (last_name, first_name)
  VALUES ('Smith', 'Robert'); DROP TABLE students; --')

These are in fact two SQL queries and one SQL comment:

Execution of such a query can lead to a serious data loss (hopefully we have made a backup copy or do not have sufficient rights to drop the students table). To avoid such problems we should properly escape parameters values in our SQL queries.

How to escape values in SQL queries?

At this point we already know that we should properly escape parameters values in our SQL queries. There are many techniques of doing that:

Manually checking data types

You can escape your data manually, e.g.

This is possible but is also very error prone, especially when escaping string values. Everyone knows that apostrophes have to be escaped, but:

It is almost impossible to remember all caveats by yourself, so it is strongly advised not to use this method.

Using parameterized queries

Another solution is to separate the query string from its parameters (data). In such case a query execution is divided into two steps:

As query parameters are passed separately, parameter values cannot modify (and break) the query string. To indicate places in the query where parameters will be placed, a special character is used, typically a question mark.

Let us rewrite our cakes example using the sqlExecute(connHandle, queryString, data) function from the RODBCext package:

library(RODBCext)

connHandle <- odbcConnect("cakesDatabase")
newData <- read.csv("newData.csv", stringsAsFactors = F)

query <- "UPDATE cakes SET price = ? WHERE cake = ?"
for(row in seq_len(nrow(newData))){
  sqlExecute(connHandle, query, newData[i, ])
}

odbcClose(connHandle)

We replaced the parameter values in query with a question mark and passed query and data as separate function parameters. We made our code not only SQL injection resistant, but also easier to read.

Moreover, the function function sqlExecute() supports vectorized data, so we can make it even simpler:

library(RODBCext)

connHandle <- odbcConnect("cakesDatabase")
newData <- read.csv("newData.csv", stringsAsFactors = F)

query <- "UPDATE cakes SET price = ? WHERE cake = ?"
sqlExecute(connHandle, query, newData)

odbcClose(connHandle)

Using high-level functions which deal with esaping values for us

This would be the most straightforward solution.

An excellent example is dplyr, which provides a complete R to SQL mapper and allows us to completely forget about the SQL. Another example are the sqlSave(), sqlUpdate(), sqlCopy() and sqlCopyTable() functions from the RODBC package which deal with escaping values for us.

The problem is that: Dplyr escapes values rather naively. With respect to strings only simple ' to '' escaping is performed which is enough to prevent silly errors but will fail against more advanced SQL injections. RODBC's high-level functions escape values in a safe way (by internally using parameterized queries), but have very limited functionality. Interestingly, judging from the comments in the source code, the parameterized queries have been introduced to them not to make them safe but to improve speed.

Summary

When using SQL we must pay attention to escape query parameter values properly. The existing R database connectivity packages do not provide a completely reliable way of doing that. A set of SQL injections safe functions provides very limited functionality and more flexible functions are using naive escaping methods. That is why RODBCext is a preferred way to make your R code SQL injections safe.

I hope dplyr developers will switch to use parameterized queries internally at some point. This would provide R community with a brilliant and safe R to SQL mapper and to forget about a manual preparation of SQL queries.

Speeding up query execution using parameterized queries

SQL query execution is being performed in a few steps. The first two steps are

If we repeat the same query many times and only values of query parameters are changing, it will be faster to perform these steps only once and then reuse the already parsed and planed query. This can be achieved by using parameterized queries.

Example - big insert

A typical scenario is an insert of many rows to a table:

library(RODBCext)
connHandle <- odbcConnect('EWD') # my sample ODBC database
data <- data.frame(1:10000, letters[rep(1:10, 1000)])

# Ordinary query - paste0() called in every loop
system.time({
  for(row in seq_len(nrow(data))){
    query <- paste0("INSERT INTO my_table VALUES (", data[row, 1], "'", data[row, 2],"')")
    sqlQuery(connHandle, query)
  }
})
#   user  system elapsed 
#  5.384   2.288  16.397

# Ordinary query - paste0() called only once
system.time({
  queries <- paste0(
    "INSERT INTO my_table VALUES (", data[, 1], "'", data[, 2],"')"
  )
  for(query in queries){
    sqlQuery(connHandle, query)
  }
})
#   user  system elapsed 
#  2.088   2.028   7.255 

# Parameterized query
system.time({
  sqlExecute(connHandle, "INSERT INTO my_table VALUES (?, ?)", data)
})
#   user  system elapsed 
#  0.300   0.232   3.935 
odbcClose(connHandle)

Example - speeding up a SELECT query

Also repeated execution of a SELECT query can benefit from using parameterized variant:

library(RODBCext)
connHandle <- odbcConnect('EWD') # my sample ODBC database

pupils = sqlQuery(
  connHandle, "SELECT id_obserwacji FROM obserwacje LIMIT 10000", 
  stringsAsFactors = F
)[, 1]

# Ordinary query - paste0() called in every loop
system.time({
  for(i in pupils){
    query <- paste0(
      "SELECT count(*) 
       FROM testy_obserwacje JOIN testy USING (id_testu) JOIN arkusze USING (arkusz) 
       WHERE id_obserwacji = ", pupils[i]
    )
    tmp <- sqlQuery(connHandle, query)
    # some other computations here
  }
})
#   user  system elapsed 
# 10.896   1.508  61.424 

# Ordinary query - paste0() called only once
system.time({
  queries <- paste0(
    "SELECT count(*) 
     FROM testy_obserwacje JOIN testy USING (id_testu) JOIN arkusze USING (arkusz) 
     WHERE id_obserwacji = ", pupils
  )
  for(query in queries){
    tmp <- sqlQuery(connHandle, query)
    # some other computations here
  }
})
#   user  system elapsed 
# 11.016   1.108  51.766 

# Parameterized query
system.time({
  query = "
    SELECT count(*) 
    FROM testy_obserwacje JOIN testy USING (id_testu) JOIN arkusze USING (arkusz) 
    WHERE id_obserwacji = ?"
  sqlPrepare(connHandle, query)
  for(i in pupils){
    tmp = sqlExecute(connHandle, NULL, pupils[i], fetch=T)
    # some other computations here
  }
})
#   user  system elapsed 
# 12.140   0.312  26.468

The longer query string, the more complicated query planning and the more query repetitions, the bigger amount of time can be saved.

Parameterized SQL queries in R

Unfortunately all known to me R packages providing support for SQL databases lacks support for parameterized queries. Even the R DBI interface doesn't define any methods which would allow to implement parameterized queries. The main reason for that is probably that R packages developers used to see SQL databases as just another storage backend for data frames rather than powerful data processing engines (which modern SQL databases already are).

RODBCext

RODBCext package tries to fill this gap by introducing parameterized queries support on the top of the RODBC package. RODBCext provides only two functions, both of them using database connection handlers from RODBC:

sqlExecute()

Allows execution of SQL queries separated from query parameters values, e.g.:

library(RODBCext)
connHandle <- odbcConnect("myDatabase")

# good old RODBC call
data <- sqlQuery(connHandle, "SELECT * FROM myTable WHERE column = 'myValue'") 
# RODBCext equivalent
data <- sqlExecute(connHandle, "SELECT * FROM myTable WHERE column = ?", 'myValue', fetch = TRUE) 

odbcClose(connHandle)

The nice thing is that sqlExecute() (in opposite to sqlQuery()) supports vectorization. In the example below data will contain results of all five queries bound by rows.

library(RODBCext)
connHandle <- odbcConnect("myDatabase")

filterData <- data.frame('column1' = 1:5, column2 = c('a', 'b', 'c', 'd', 'e'))
data <- sqlExecute(connHandle, "SELECT * FROM myTable WHERE column1 = ? AND column2 = ?", filterData, fetch = TRUE)

odbcClose(connHandle)

Results can be also fetched separately using RODBC's sqlGetResults(). This also provides a way to fetch results in parts:

library(RODBCext)
connHandle <- odbcConnect("myDatabase")

sqlExecute(connHandle, "SELECT * FROM myTable WHERE column = ?", 'myValue', fetch = FALSE)
data <- sqlGetResults(connHandle, max = 10) # fetch no more than 10 first rows
# data processing comes here
data <- sqlGetResults(connHandle) # fetch all other rows

odbcClose(connHandle)

As sqlExecute() uses internally sqlGetResults() to fetch results of the query, it also accept all parameters of the sqlGetResults():

library(RODBCext)
connHandle <- odbcConnect("myDatabase")

sqlExecute(
  connHandle, "SELECT * FROM myTable WHERE column = ?", 'myValue', 
  fetch = TRUE, stringsAsFactors = FALSE, dec = ",", max = 50, as.is = TRUE
)

odbcClose(connHandle)

sqlPrepare()

Parses a query string and plans a query. Query can be executed later using sqlExecute() with a parameter query set too NULL. This can provide some performance gain when executing the same query multiple times (see the chapter Speeding up query execution using parameterized queries). Usage example:

library(RODBCext)
connHandle <- odbcConnect('myDatabase') 

sqlPrepare(connHandle, "SELECT * FROM myTable WHERE column = ?") # prepare query

# for some reason (e.g. resources limits) data must be processed sequentialy
foreach(i in observations){
  data = sqlExecute(connHandle, NULL, i$column, fetch=T)
  # data processing for a given observations goes here
}
odbcClose(connHandle)


Try the RODBCext package in your browser

Any scripts or data that you put into this service are public.

RODBCext documentation built on Feb. 6, 2020, 5:10 p.m.