File: join.tbl_sql.Rd

package info (click to toggle)
r-cran-dbplyr 2.5.0%2Bdfsg-1
  • links: PTS, VCS
  • area: main
  • in suites: sid, trixie
  • size: 2,644 kB
  • sloc: sh: 13; makefile: 2
file content (245 lines) | stat: -rw-r--r-- 7,804 bytes parent folder | download
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
% Generated by roxygen2: do not edit by hand
% Please edit documentation in R/verb-joins.R
\name{join.tbl_sql}
\alias{join.tbl_sql}
\alias{inner_join.tbl_lazy}
\alias{left_join.tbl_lazy}
\alias{right_join.tbl_lazy}
\alias{full_join.tbl_lazy}
\alias{cross_join.tbl_lazy}
\alias{semi_join.tbl_lazy}
\alias{anti_join.tbl_lazy}
\title{Join SQL tables}
\usage{
\method{inner_join}{tbl_lazy}(
  x,
  y,
  by = NULL,
  copy = FALSE,
  suffix = NULL,
  ...,
  keep = NULL,
  na_matches = c("never", "na"),
  multiple = NULL,
  unmatched = "drop",
  relationship = NULL,
  sql_on = NULL,
  auto_index = FALSE,
  x_as = NULL,
  y_as = NULL
)

\method{left_join}{tbl_lazy}(
  x,
  y,
  by = NULL,
  copy = FALSE,
  suffix = NULL,
  ...,
  keep = NULL,
  na_matches = c("never", "na"),
  multiple = NULL,
  unmatched = "drop",
  relationship = NULL,
  sql_on = NULL,
  auto_index = FALSE,
  x_as = NULL,
  y_as = NULL
)

\method{right_join}{tbl_lazy}(
  x,
  y,
  by = NULL,
  copy = FALSE,
  suffix = NULL,
  ...,
  keep = NULL,
  na_matches = c("never", "na"),
  multiple = NULL,
  unmatched = "drop",
  relationship = NULL,
  sql_on = NULL,
  auto_index = FALSE,
  x_as = NULL,
  y_as = NULL
)

\method{full_join}{tbl_lazy}(
  x,
  y,
  by = NULL,
  copy = FALSE,
  suffix = NULL,
  ...,
  keep = NULL,
  na_matches = c("never", "na"),
  multiple = NULL,
  relationship = NULL,
  sql_on = NULL,
  auto_index = FALSE,
  x_as = NULL,
  y_as = NULL
)

\method{cross_join}{tbl_lazy}(
  x,
  y,
  ...,
  copy = FALSE,
  suffix = c(".x", ".y"),
  x_as = NULL,
  y_as = NULL
)

\method{semi_join}{tbl_lazy}(
  x,
  y,
  by = NULL,
  copy = FALSE,
  ...,
  na_matches = c("never", "na"),
  sql_on = NULL,
  auto_index = FALSE,
  x_as = NULL,
  y_as = NULL
)

\method{anti_join}{tbl_lazy}(
  x,
  y,
  by = NULL,
  copy = FALSE,
  ...,
  na_matches = c("never", "na"),
  sql_on = NULL,
  auto_index = FALSE,
  x_as = NULL,
  y_as = NULL
)
}
\arguments{
\item{x, y}{A pair of lazy data frames backed by database queries.}

\item{by}{A join specification created with \code{\link[dplyr:join_by]{join_by()}}, or a character
vector of variables to join by.

If \code{NULL}, the default, \verb{*_join()} will perform a natural join, using all
variables in common across \code{x} and \code{y}. A message lists the variables so
that you can check they're correct; suppress the message by supplying \code{by}
explicitly.

To join on different variables between \code{x} and \code{y}, use a \code{\link[dplyr:join_by]{join_by()}}
specification. For example, \code{join_by(a == b)} will match \code{x$a} to \code{y$b}.

To join by multiple variables, use a \code{\link[dplyr:join_by]{join_by()}} specification with
multiple expressions. For example, \code{join_by(a == b, c == d)} will match
\code{x$a} to \code{y$b} and \code{x$c} to \code{y$d}. If the column names are the same between
\code{x} and \code{y}, you can shorten this by listing only the variable names, like
\code{join_by(a, c)}.

\code{\link[dplyr:join_by]{join_by()}} can also be used to perform inequality, rolling, and overlap
joins. See the documentation at \link[dplyr:join_by]{?join_by} for details on
these types of joins.

For simple equality joins, you can alternatively specify a character vector
of variable names to join by. For example, \code{by = c("a", "b")} joins \code{x$a}
to \code{y$a} and \code{x$b} to \code{y$b}. If variable names differ between \code{x} and \code{y},
use a named character vector like \code{by = c("x_a" = "y_a", "x_b" = "y_b")}.

To perform a cross-join, generating all combinations of \code{x} and \code{y}, see
\code{\link[dplyr:cross_join]{cross_join()}}.}

\item{copy}{If \code{x} and \code{y} are not from the same data source,
and \code{copy} is \code{TRUE}, then \code{y} will be copied into a
temporary table in same database as \code{x}. \verb{*_join()} will automatically
run \code{ANALYZE} on the created table in the hope that this will make
you queries as efficient as possible by giving more data to the query
planner.

This allows you to join tables across srcs, but it's potentially expensive
operation so you must opt into it.}

\item{suffix}{If there are non-joined duplicate variables in \code{x} and
\code{y}, these suffixes will be added to the output to disambiguate them.
Should be a character vector of length 2.}

\item{...}{Other parameters passed onto methods.}

\item{keep}{Should the join keys from both \code{x} and \code{y} be preserved in the
output?
\itemize{
\item If \code{NULL}, the default, joins on equality retain only the keys from \code{x},
while joins on inequality retain the keys from both inputs.
\item If \code{TRUE}, all keys from both inputs are retained.
\item If \code{FALSE}, only keys from \code{x} are retained. For right and full joins,
the data in key columns corresponding to rows that only exist in \code{y} are
merged into the key columns from \code{x}. Can't be used when joining on
inequality conditions.
}}

\item{na_matches}{Should NA (NULL) values match one another?
The default, "never", is how databases usually work. \code{"na"} makes
the joins behave like the dplyr join functions, \code{\link[=merge]{merge()}}, \code{\link[=match]{match()}},
and \code{\%in\%}.}

\item{multiple, unmatched}{Unsupported in database backends. As a workaround
for multiple use a unique key and for unmatched a foreign key constraint.}

\item{relationship}{Unsupported in database backends.}

\item{sql_on}{A custom join predicate as an SQL expression.
Usually joins use column equality, but you can perform more complex
queries by supply \code{sql_on} which should be a SQL expression that
uses \code{LHS} and \code{RHS} aliases to refer to the left-hand side or
right-hand side of the join respectively.}

\item{auto_index}{if \code{copy} is \code{TRUE}, automatically create
indices for the variables in \code{by}. This may speed up the join if
there are matching indexes in \code{x}.}

\item{x_as, y_as}{Alias to use for \code{x} resp. \code{y}. Defaults to \code{"LHS"} resp.
\code{"RHS"}}
}
\value{
Another \code{tbl_lazy}. Use \code{\link[=show_query]{show_query()}} to see the generated
query, and use \code{\link[=collect.tbl_sql]{collect()}} to execute the query
and return data to R.
}
\description{
These are methods for the dplyr \link{join} generics. They are translated
to the following SQL queries:
\itemize{
\item \code{inner_join(x, y)}: \verb{SELECT * FROM x JOIN y ON x.a = y.a}
\item \code{left_join(x, y)}:  \verb{SELECT * FROM x LEFT JOIN y ON x.a = y.a}
\item \code{right_join(x, y)}: \verb{SELECT * FROM x RIGHT JOIN y ON x.a = y.a}
\item \code{full_join(x, y)}:  \verb{SELECT * FROM x FULL JOIN y ON x.a = y.a}
\item \code{semi_join(x, y)}:  \verb{SELECT * FROM x WHERE EXISTS (SELECT 1 FROM y WHERE x.a = y.a)}
\item \code{anti_join(x, y)}:  \verb{SELECT * FROM x WHERE NOT EXISTS (SELECT 1 FROM y WHERE x.a = y.a)}
}
}
\examples{
library(dplyr, warn.conflicts = FALSE)

band_db <- tbl_memdb(dplyr::band_members)
instrument_db <- tbl_memdb(dplyr::band_instruments)
band_db \%>\% left_join(instrument_db) \%>\% show_query()

# Can join with local data frames by setting copy = TRUE
band_db \%>\%
  left_join(dplyr::band_instruments, copy = TRUE)

# Unlike R, joins in SQL don't usually match NAs (NULLs)
db <- memdb_frame(x = c(1, 2, NA))
label <- memdb_frame(x = c(1, NA), label = c("one", "missing"))
db \%>\% left_join(label, by = "x")
# But you can activate R's usual behaviour with the na_matches argument
db \%>\% left_join(label, by = "x", na_matches = "na")

# By default, joins are equijoins, but you can use `sql_on` to
# express richer relationships
db1 <- memdb_frame(x = 1:5)
db2 <- memdb_frame(x = 1:3, y = letters[1:3])
db1 \%>\% left_join(db2) \%>\% show_query()
db1 \%>\% left_join(db2, sql_on = "LHS.x < RHS.x") \%>\% show_query()
}