590 lines
24 KiB
Plaintext
590 lines
24 KiB
Plaintext
# Databases {#sec-import-databases}
|
|
|
|
```{r}
|
|
#| results: "asis"
|
|
#| echo: false
|
|
source("_common.R")
|
|
status("drafting")
|
|
```
|
|
|
|
## Introduction
|
|
|
|
A huge amount of data lives in databases, and it's essential that as a data scientist you know how to access it.
|
|
Sometimes it's possible to get someone to download a snapshot into a .csv for you, but this is generally not desirable as the iteration speed is very slow.
|
|
You want to be able to reach into the database directly to get the data you need, when you need it.
|
|
|
|
In this chapter, you'll first learn the basics of the DBI package: how to use it to connect to a database and how to retrieve data by executing an SQL query.
|
|
**SQL**, short for **s**tructured **q**uery **l**anguage, is the lingua franca of databases, and is an important language for you to learn as a data scientist.
|
|
However, we're not going to start with SQL, but instead we'll teach you dbplyr, which can convert your dplyr code to the equivalent SQL.
|
|
We'll use that as way to teach you some of the most important features of SQL.
|
|
You won't become a SQL master by the end of the chapter, but you will be able to identify the most important components and understand what they do.
|
|
|
|
The main focus of this chapter, is working with data that already exists, data that someone else has collected in a database for you, as this represents the most common case.
|
|
But as we go along, we will point out a few tips and tricks for getting your own data into a database.
|
|
|
|
### Prerequisites
|
|
|
|
In this chapter, we'll add DBI and dbplyr into the mix.
|
|
DBI provides a low-level interface for connecting to databases and executing SQL.
|
|
dbplyr is a high-level interface that works with dplyr verbs to automatically generate SQL and then executes it using DBI.
|
|
|
|
```{r}
|
|
#| label: setup
|
|
#| message: false
|
|
library(DBI)
|
|
library(dbplyr)
|
|
library(tidyverse)
|
|
```
|
|
|
|
## Database basics
|
|
|
|
At the simplest level, you can think about a database as a collection of data frames, called **tables** in database terminology.
|
|
Like a data.frame, a database table is a collection of named columns, where every value in the column is the same type.
|
|
There are three high level differences between data frames and database tables:
|
|
|
|
- Database tables are stored on disk and can be arbitrarily large.
|
|
Data frames are stored in memory, and hence can't be bigger than your memory.
|
|
|
|
- Database tables usually have indexes.
|
|
Much like an index of a book, a database index makes it possible to find rows of interest without having to read every row.
|
|
Data frames and tibbles don't have indexes, but data.tables do, which is one of the reasons that they're so fast.
|
|
|
|
- Most classical databases are optimized for rapidly collecting data, not analyzing existing data.
|
|
These databases are called **row-oriented** because the data is stored row-by-row, rather than column-by-column like R.
|
|
More recently, there's been much development of **column-oriented** databases that make analyzing the existing data much faster.
|
|
|
|
Databases are run by database management systems (**DBMS** for short), which are typically run on a powerful central server.
|
|
Popular open source DBMS's of this nature are MariaDB, PostgreSQL, and SQL, and commercial equivalents include SQL Server and Oracle.
|
|
Today, many DBMS's run in the cloud, like Snowflake, Amazon's RedShift, and Google's BigQuery.
|
|
|
|
## Connecting to a database
|
|
|
|
To connect to the database from R, you'll use a pair of packages:
|
|
|
|
- You'll always use DBI (**d**ata**b**ase **i**nterface), provides a set of generic functions that perform connect to the database, upload data, run queries, and so on.
|
|
|
|
- You'll also use a DBMS client package package specific to the DBMS you're connecting to.
|
|
This package translates the generic commands into the specifics needed for a given DBMS.
|
|
For example, if you're connecting to Postgres you'll use the RPostgres package.
|
|
If you're connecting to MariaDB or MySQL, you'll use the RMariaDB package.
|
|
|
|
If you can't find a specific package for your DBMS, you can usually use the generic odbc package instead.
|
|
This uses the widespread ODBC standard.
|
|
odbc requires a little more setup because you'll also need to install and configure an ODBC driver.
|
|
|
|
Concretely, to create a database connection using `DBI::dbConnect()`.
|
|
The first argument specifies the DBMS and the second and subsequent arguments describe where the database lives and any credentials that you'll need to access it.
|
|
The following code shows are few typical examples:
|
|
|
|
```{r}
|
|
#| eval: false
|
|
con <- DBI::dbConnect(
|
|
RMariaDB::MariaDB(),
|
|
username = "foo"
|
|
)
|
|
con <- DBI::dbConnect(
|
|
RPostgres::Postgres(),
|
|
hostname = "databases.mycompany.com",
|
|
port = 1234
|
|
)
|
|
```
|
|
|
|
There's a lot of variation from DBMs to DBMS so unfortunately we can't cover all the details here.
|
|
So to connect the database you care about, you'll need to do a little research.
|
|
Typically you can ask the other data scientists in your team or talk to your DBA (**d**ata**b**ase **a**dministrator).
|
|
The initial setup will often take a little fiddling (and maybe some googling) to get right, but you'll generally only need to do it once.
|
|
|
|
When you're done with the connection it's good practice to close it with `dbDisconnect(con)`.
|
|
This frees up resources on the database server for us by other people.
|
|
|
|
### In this book
|
|
|
|
Setting up a DBMS would be a pain for this book, so we'll instead use a self-contained DBMS that lives entirely in an R package: duckdb.
|
|
Thanks to the magic of DBI, the only difference between using duckdb and any other DBMS is how you'll connect to the database.
|
|
This makes it great to teach with because you can easily run this code as well as easily take what you learn and apply it elsewhere.
|
|
|
|
Connecting to duckdb is particularly simple because the defaults create a temporary database that is deleted when you quite R.
|
|
That's great for learning because it guarantees that you'll start from a clean slate every time you restart R:
|
|
|
|
```{r}
|
|
con <- DBI::dbConnect(duckdb::duckdb())
|
|
```
|
|
|
|
If you want to use duckdb for a real data analysis project[^import-databases-1], you'll also need to supply the `dbdir` argument to tell duckdb where to store the database files.
|
|
Assuming you're using a project (Chapter -@sec-workflow-scripts-projects)), it's reasonable to store it in the `duckdb` directory of the current project:
|
|
|
|
[^import-databases-1]: Which we highly recommend: it's a great database for data science.
|
|
|
|
```{r}
|
|
#| eval: false
|
|
con <- DBI::dbConnect(duckdb::duckdb(), dbdir = "duckdb")
|
|
```
|
|
|
|
duckdb is a high-performance database that's designed very much with the needs of the data scientist in mind, and the developers very much understand R and the types of real problems that R users face.
|
|
As you'll see in this chapter, it's really easy to get started with but it can also handle very large datasets.
|
|
|
|
### Load some data {#sec-load-data}
|
|
|
|
Since this is a temporary database, we need to start by adding some data.
|
|
Here we'll use the `mpg` and `diamonds` datasets from ggplot2.
|
|
|
|
```{r}
|
|
dbWriteTable(con, "mpg", ggplot2::mpg)
|
|
dbWriteTable(con, "diamonds", ggplot2::diamonds)
|
|
```
|
|
|
|
If you're using duckdb in a real project, I highly recommend learning about `duckdb_read_csv()` and `duckdb_register_arrow()`.
|
|
These give you powerful and performant ways to quickly load data directly into duckdb, without having to first load it in to R.
|
|
|
|
## Database basics
|
|
|
|
Now that we've connected to a database with some data in it, lets perform some basic operations with DBI.
|
|
|
|
### What's there?
|
|
|
|
The most important database objects for data scientists are tables.
|
|
DBI provides two useful functions to either list all the tables in the database[^import-databases-2] or to check if a specific table already exists:
|
|
|
|
[^import-databases-2]: At least, all the tables that you have permission to see.
|
|
|
|
```{r}
|
|
dbListTables(con)
|
|
dbExistsTable(con, "foo")
|
|
```
|
|
|
|
### Extract some data
|
|
|
|
Once you've determined a table exists, you can retrieve it with `dbReadTable()`:
|
|
|
|
```{r}
|
|
con |>
|
|
dbReadTable("diamonds") |>
|
|
as_tibble()
|
|
```
|
|
|
|
`dbReadTable()` returns a `data.frame` so I use `as_tibble()` to convert it into a tibble so that it prints nicely.
|
|
|
|
```{=html}
|
|
<!--
|
|
Notice something important with the diamonds dataset: the `cut`, `color`, and `clarity` columns were originally ordered factors, but now they're regular factors.
|
|
This particularly case isn't very important since ordered factors are barely different to regular factors, but it's good to know that the way that the database represents data can be slightly different to the way R represents data.
|
|
In this case, we're actually quite lucky because most databases don't support factors at all and would've converted the column to a string.
|
|
Again, not that important, because most of the time you'll be working with data that lives in a database, but good to be aware of if you're storing your own data into a database.
|
|
Generally you can expect numbers, strings, dates, and date-times to convert just fine, but other types may not.
|
|
-->
|
|
```
|
|
In real life, it's rare that you'll use `dbReadTable()` because the whole reason you're using a database is that there's too much data to fit in a data frame, and you want to use the database to bring back only a subset of the rows and columns.
|
|
|
|
### Run a query {#sec-dbGetQuery}
|
|
|
|
The way you'll usually retrieve data is with `dbGetQuery()`.
|
|
It takes a database connection and some SQL code and returns a data frame:
|
|
|
|
```{r}
|
|
con |>
|
|
dbGetQuery("
|
|
SELECT carat, cut, clarity, color, price
|
|
FROM diamonds
|
|
WHERE price > 15000
|
|
") |>
|
|
as_tibble()
|
|
```
|
|
|
|
Don't worry if you've never seen SQL code before as you'll learn more about it shortly.
|
|
But if read it carefully, you might guess that it selects five columns of the diamonds dataset and the rows where `price` is greater than 15,000.
|
|
|
|
You'll need to be a little careful with `dbGetQuery()` since it can potentially return more data than you have memory.
|
|
We won't discuss it further here, but if you're dealing with very large datasets it's possible to deal with a "page" of data at a time by using `dbSendQuery()` to get a "result set" which you can page through by calling `dbFetch()` until `dbHasCompleted()` returns `TRUE`.
|
|
|
|
### Other functions
|
|
|
|
There are lots of other functions in DBI that you might find useful if you're managing your own data (like `dbWriteTable()` which we used in @sec-load-data), but we're going to skip past them in the interests of staying focused on working with data that already lives in a database.
|
|
|
|
## dbplyr basics
|
|
|
|
Now that you've learned the low-level basics for connecting to a database and running a query, we're going to switch it up a bit and learn a bit about dbplyr.
|
|
dbplyr is a dplyr **backend**, which means that you write the dplyr code that you're already familiar with and dbplyr translates it to run in a different way, in this case to SQL.
|
|
|
|
To use dbplyr, you must first use `tbl()` to create an object that represents a database table[^import-databases-3]:
|
|
|
|
[^import-databases-3]: If you want to mix SQL and dbplyr, you can also create a tbl from a SQL query with `tbl(con, SQL("SELECT * FROM foo")).`
|
|
|
|
```{r}
|
|
diamonds_db <- tbl(con, "diamonds")
|
|
diamonds_db
|
|
```
|
|
|
|
This object is **lazy**; when you use dplyr verbs on it, dplyr doesn't do any work: it just records the sequence of operations that you want to perform and only performs them when needed.
|
|
For example, take the following pipeline:
|
|
|
|
```{r}
|
|
big_diamonds_db <- diamonds_db |>
|
|
filter(price > 15000) |>
|
|
select(carat:clarity, price)
|
|
|
|
big_diamonds_db
|
|
```
|
|
|
|
You can tell this object represents a database query because it prints the DBMS name at the top, and while it tells you the number of columns, it typically it won't tell you the number of rows.
|
|
This is because finding the total number of rows usually requires executing the complete query, something we're trying to avoid.
|
|
|
|
You can see the SQL the dbplyr generates by a dbplyr query by calling `show_query()`:
|
|
|
|
```{r}
|
|
big_diamonds_db |>
|
|
show_query()
|
|
```
|
|
|
|
To get all the data back into R, you call `collect()`.
|
|
Behind the scenes, this generates the SQL, calls `dbGetQuery()` to get the data, then turns the result into a tibble:
|
|
|
|
```{r}
|
|
big_diamonds <- big_diamonds_db |>
|
|
collect()
|
|
big_diamonds
|
|
```
|
|
|
|
## SQL
|
|
|
|
The rest of the chapter will teach you a little about SQL through the lens of dbplyr.
|
|
It's a rather non-traditional introduction to SQL but I hope it will get you quickly up to speed with the basics.
|
|
It will hopefully help you understand the parallels between SQL and dplyr but it's not going to give you much practice writing SQL.
|
|
For that, I'd recommend [*SQL for Data Scientists*](https://sqlfordatascientists.com)by Renée M. P. Teate.
|
|
It's an introduction to SQL designed specifically for the needs of data scientists, and includes examples of the sort of highly interconnected data you're likely to encounter in real organizations.
|
|
|
|
Luckily, if you understand dplyr you're in a great place to quickly pick up SQL because so many of the concepts are the same.
|
|
|
|
We'll explore the relationship between dplyr and SQL using a couple of old friends from the nycflights dataset, the `flights` and `planes` tibbles.
|
|
These are easy to get into our learning database because dbplyr has a function designed for this exact scenario.
|
|
|
|
```{r}
|
|
dbplyr::copy_nycflights13(con)
|
|
flights <- tbl(con, "flights")
|
|
planes <- tbl(con, "planes")
|
|
|
|
options(dplyr.strict_sql = TRUE)
|
|
```
|
|
|
|
### SQL basics
|
|
|
|
Instead of functions, like R, SQL has **statements**.
|
|
Common statements include `CREATE` for defining new tables, `INSERT` for adding data, and `SELECT` for retrieving data.
|
|
We're going to focus on `SELECT` statements, aka **queries**, because they are almost exclusively what you'll use as a data scientist.
|
|
Your job is usually to analyse existing data, and in most cases you won't even have permission to modify the data.
|
|
|
|
A query is made up of **clauses**.
|
|
Every query must have two clauses `SELECT` and `FROM`[^import-databases-4].
|
|
The simplest query is uses `SELECT * FROM tablename` to select columns from the specified table.
|
|
This is what dplyr generates for an adulterated table:
|
|
|
|
[^import-databases-4]: Ok, technically, only the `SELECT` is required, since you can write queries like `SELECT 1+1` to perform basic calculation.
|
|
But if you want to work with data (as you always do!) you'll also need a `FROM` clause.
|
|
|
|
```{r}
|
|
flights |> show_query()
|
|
planes |> show_query()
|
|
```
|
|
|
|
There are three other important clauses: `WHERE`, `ORDER BY`, and `GROUP BY`. `WHERE` and `ORDER BY` control which rows are included in the result and how they are ordered:
|
|
|
|
```{r}
|
|
flights |>
|
|
filter(dest == "IAH") |>
|
|
arrange(dep_delay) |>
|
|
show_query()
|
|
```
|
|
|
|
While `GROUP BY` works just like `dplyr::group_by()` causing aggregation to happen by group:
|
|
|
|
```{r}
|
|
flights |>
|
|
group_by(dest) |>
|
|
summarise(dep_delay = mean(dep_delay, na.rm = TRUE)) |>
|
|
show_query()
|
|
```
|
|
|
|
There are two important differences between dplyr verbs and SELECT clauses:
|
|
|
|
- SQL, unlike R, is **case** **insensitive** so you can write `select`, `SELECT`, or even `SeLeCt`. In this book we'll stick with the common convention of writing SQL keywords in uppercase to distinguish them from table or variables names.
|
|
- In SQL, order matters. Unlike dplyr, where you can call the verbs in whatever order makes the most sense to you, SQL clauses must come in a specific order: `SELECT`, `FROM`, `WHERE`, `GROUP BY`, `ORDER BY`. Confusingly, this order doesn't match how they are actually evaluated, which is `FROM`, `WHERE`, `GROUP BY`, `SELECT`, `ORDER BY`.
|
|
|
|
The following sections will explore each clause in more detail.
|
|
|
|
::: callout-note
|
|
Note that every database uses a slightly different dialect of SQL.
|
|
For the vast majority of simple examples in this chapter, you won't see any differences.
|
|
But as you start to write more complex SQL you'll discover that what works on what database might not work on another.
|
|
Fortunately, dbplyr will take care a lot of this for you, as it automatically varies the SQL that it generates based on the database you're using.
|
|
It's not perfect, but if you discover the dbplyr creates SQL that works on one database but not another, please file an issue so we can try to make it better.
|
|
:::
|
|
|
|
### SELECT
|
|
|
|
`SELECT` is the workhorse of SQL queries, and is equivalent to `select()`, `mutate()`, `rename()`, `relocate()`, and, as you'll learn in the next section, `summarize()`.
|
|
`select()`, `rename()`, and `relocate()` have very direct translations to `SELECT` as they affect where a column appears (if at all) along with its name:
|
|
|
|
```{r}
|
|
flights |>
|
|
select(year:day, starts_with("dep")) |>
|
|
show_query()
|
|
|
|
flights |>
|
|
rename(tail_num = tailnum) |>
|
|
show_query()
|
|
|
|
flights |>
|
|
relocate(hour:minute, .after = day) |>
|
|
show_query()
|
|
```
|
|
|
|
This example also shows you how SQL does renaming.
|
|
In SQL terminology renaming is called **aliasing** and is done with `AS`.
|
|
Note that unlike with `mutate()`, the old name is on the left and the new name is on the right.
|
|
|
|
The translations for `mutate()` are similarly straightforward.
|
|
We'll come back to the translation of individual components in @sec-sql-expressions.
|
|
|
|
```{r}
|
|
diamonds_db |>
|
|
mutate(price_per_carat = price / carat) |>
|
|
show_query()
|
|
```
|
|
|
|
::: callout-note
|
|
When working with other databases you're likely to see variable names wrapped in some sort of quote, e.g.
|
|
|
|
``` sql
|
|
SELECT "year", "month", "day", "dep_time", "dep_delay"
|
|
FROM "flights"
|
|
```
|
|
|
|
Or maybe
|
|
|
|
``` sql
|
|
SELECT `year`, `month`, `day`, `dep_time`, `dep_delay`
|
|
FROM `flights`
|
|
```
|
|
|
|
Technically, you only need to quote special **reserved words** like `SELECT` or `FROM`.
|
|
But only a handle of DBMS clients, like duckdb, actually know the complete list of reserved words, so most clients quote everything just to be safe.
|
|
:::
|
|
|
|
### GROUP BY
|
|
|
|
When paired with `group_by()`, `summarise()` is also translated to `SELECT`:
|
|
|
|
```{r}
|
|
diamonds_db |>
|
|
group_by(cut) |>
|
|
summarise(
|
|
n = n(),
|
|
avg_price = mean(price, na.rm = TRUE)
|
|
) |>
|
|
show_query()
|
|
```
|
|
|
|
We'll come back to the translations of `n()` and `mean()` in @sec-sql-expressions.
|
|
But it's no coincidence that `group_by()` is translated to `GROUP BY`: the SQL clause inspired the R function name.
|
|
|
|
### WHERE
|
|
|
|
`filter()` is translated to `WHERE`.
|
|
`|` becomes `OR` and `&` becomes `AND:`
|
|
|
|
```{r}
|
|
flights |>
|
|
filter(dest == "IAH" | dest == "HOU") |>
|
|
show_query()
|
|
|
|
flights |>
|
|
filter(arr_delay > 0 & arr_delay < 20) |>
|
|
show_query()
|
|
```
|
|
|
|
Note that SQL uses `=` for comparison, not `==`.
|
|
This is super annoying if you're switching between writing R code and SQL!
|
|
Also note that SQL always uses `''` for strings --- you can't use `""` in because it's equivalent to ``` `` ``` in R!
|
|
|
|
Another useful SQL function is `IN`, which is very close to R's `%in%`:
|
|
|
|
```{r}
|
|
flights |>
|
|
filter(dest %in% c("IAH", "HOU")) |>
|
|
show_query()
|
|
```
|
|
|
|
SQL doesn't have `NA`s, but instead it has `NULL`s.
|
|
They behave very similarly to `NA`s, including their "infectious" properties.
|
|
|
|
```{r}
|
|
flights |>
|
|
filter(!is.na(dep_delay)) |>
|
|
show_query()
|
|
```
|
|
|
|
This SQL query illustrates one of the drawbacks of dbplyr: it doesn't always generate the simplest SQL.
|
|
In this case, the parentheses are redundant and you could use the special form `IS NOT NULL` yielding:
|
|
|
|
``` sql
|
|
WHERE "dep_delay" IS NOT NULL
|
|
```
|
|
|
|
### ORDER BY
|
|
|
|
Ordering rows involes a straightforward translation from `arrange()` to `ORDER BY`:
|
|
|
|
```{r}
|
|
flights |>
|
|
arrange(year, month, day, desc(dep_delay)) |>
|
|
show_query()
|
|
```
|
|
|
|
Note that `desc()` becomes `DESC`; this is another R function whose named was directly inspired by SQL.
|
|
|
|
### Subqueries
|
|
|
|
Sometimes it's not possible to express what you want in a single query.
|
|
For example, in `SELECT` you can only refer to columns that exist in the `FROM`, not columns that you have just created.
|
|
|
|
So if you modify a column that you just created, dbplyr will need to create a subquery:
|
|
|
|
```{r}
|
|
diamonds_db |>
|
|
select(carat) |>
|
|
mutate(
|
|
carat2 = carat + 2,
|
|
carat3 = carat2 + 1
|
|
) |>
|
|
show_query()
|
|
```
|
|
|
|
A subquery is just a query that's nested inside of `FROM`, so instead of a table being used as the source, the new query is.
|
|
|
|
Another similar restriction is that `WHERE`, like `SELECT` can only operate on variables in `FROM`, so if you try and filter based on a variable that you just created, you'll need to create a subquery.
|
|
|
|
```{r}
|
|
diamonds_db |>
|
|
select(carat) |>
|
|
mutate(carat2 = carat + 2) |>
|
|
filter(carat2 > 1) |>
|
|
show_query()
|
|
```
|
|
|
|
Sometimes dbplyr uses a subquery where strictly speaking it's not necessary.
|
|
For example, take this pipeline that filters on a summary value.
|
|
|
|
### Joins
|
|
|
|
SQL joins are straightforward, but dbplyr's current translations are rather verbose (we're working on doing better in the future, so if you're lucky it'll be better by the time you're reading this):
|
|
|
|
```{r}
|
|
flights |>
|
|
left_join(planes, by = "tailnum") |>
|
|
show_query()
|
|
```
|
|
|
|
You'd typically write this more like:
|
|
|
|
``` sql
|
|
SELECT flights.*, "type", manufacturer, model, engines, seats, speed
|
|
FROM flights
|
|
LEFT JOIN planes ON (flights.tailnum = planes.tailnum)
|
|
```
|
|
|
|
You might guess that this is the SQL you'd use for `right_join()` and `full_join()`
|
|
|
|
``` sql
|
|
SELECT flights.*, "type", manufacturer, model, engines, seats, speed
|
|
FROM flights
|
|
RIGHT JOIN planes ON (flights.tailnum = planes.tailnum)
|
|
|
|
SELECT flights.*, "type", manufacturer, model, engines, seats, speed
|
|
FROM flights
|
|
FULL JOIN planes ON (flights.tailnum = planes.tailnum)
|
|
```
|
|
|
|
And you'd be right!
|
|
The names for dbplyrs join functions were directly inspired by SQL.
|
|
|
|
### Temporary data
|
|
|
|
Sometimes it's useful to perform a join or semi/anti join with data that you have locally.
|
|
How can you get that data into the database?
|
|
There are a few ways to do so.
|
|
You can set `copy = TRUE` to automatically copy.
|
|
There are two other ways that give you a little more control:
|
|
|
|
`copy_to()` --- this works very similarly to `DBI::dbWriteTable()` but returns a `tbl` so you don't need to create one after the fact.
|
|
By default this creates a temporary table, which will only be visible to the current connection (not to other people using the database), and will automatically be deleted when the connection finishes.
|
|
Most database will allow you to create temporary tables, even if you don't otherwise have write access to the data.
|
|
|
|
`copy_inline()` --- new in the latest version of db.
|
|
Rather than copying the data to the database, it builds SQL that generates the data inline.
|
|
It's useful if you don't have permission to create temporary tables, and is faster than `copy_to()` for small datasets.
|
|
|
|
### Other verbs
|
|
|
|
dbplyr provides translation for other dplyr verbs like `distinct()`, `slice_*()`, and `intersect()`, and a growing selection of tidyr functions like `pivot_longer()` and `pivot_wider()`.
|
|
The easiest way to see the full set of what's currently available is to visit the dbplyr website: <https://dbplyr.tidyverse.org/reference/>.
|
|
|
|
## Function translations {#sec-sql-expressions}
|
|
|
|
So far we've focussed on the big picture of how dplyr verbs are translated in to `SELECT` clauses.
|
|
Now we're going to zoom in a little and talk about how individual R functions are translated, i.e. what happens when you use `mean(x)` in a `summarize()`?
|
|
The translation is certainly not perfect, and there are many R functions that aren't converted to SQL, but dbplyr does a surprisingly good job covering the functions that you'll use most of the time.
|
|
|
|
To explore these translations I'm going to make a couple of little helper functions that run a `summarise()` or `mutate()` and return the generated SQL.
|
|
That'll make it a little easier to explore some variations.
|
|
|
|
```{r}
|
|
show_summarize <- function(df, ...) {
|
|
df |>
|
|
summarise(...) |>
|
|
show_query()
|
|
}
|
|
show_mutate <- function(df, ...) {
|
|
df |>
|
|
mutate(...) |>
|
|
show_query()
|
|
}
|
|
```
|
|
|
|
```{r}
|
|
flights |> show_summarize(
|
|
mean = mean(arr_delay, na.rm = TRUE),
|
|
# sd = sd(arr_delay, na.rm = TRUE),
|
|
median = median(arr_delay, na.rm = TRUE)
|
|
)
|
|
```
|
|
|
|
- Most mathematical operators are the same.
|
|
The exception is `^`:
|
|
|
|
```{r}
|
|
flights |> show_mutate(x = 1 + 2 * 3 / 4 ^ 5)
|
|
```
|
|
|
|
- In R, the default for a number is to be a double, i.e. `2` is a double and `2L` is an integer.
|
|
In SQL, the default is for a number to be an integer unless you put a `.0` after it:
|
|
|
|
```{r}
|
|
flights |> show_mutate(2 + 2L)
|
|
```
|
|
|
|
This is more important in SQL than in R because if you do `(x + y) / 2` in SQL it will use integer division.
|
|
|
|
- `ifelse()` and `case_when()` are translated to CASE WHEN:
|
|
|
|
```{r}
|
|
flights |> show_mutate(if_else(x > 5, "big", "small"))
|
|
```
|
|
|
|
- String functions
|
|
|
|
```{r}
|
|
flights |> show_mutate(paste0("Greetings ", name))
|
|
```
|
|
|
|
dbplyr also translates common string and date-time manipulation functions.
|
|
You can learn more about these functions in `vignette("translation-function", package = "dbplyr")`.
|