The package provides a Teradata backend for dplyr.
373 |It makes it possible to operate Teradata Database in the same way as manipulating data frames with dplyr.
374 |library(dplyr.teradata)
375 |
376 | # Establish a connection to Teradata
377 | con <- dbConnect(todbc(),
378 | driver = "{Teradata Driver}", DBCName = "host_name_or_IP_address",
379 | uid = "user_name", pwd = "*****")
380 | my_table <- tbl(con, "my_table_name")
381 |
382 | # Build a query
383 | q <- my_table %>%
384 | filter(between(date, "2017-01-01", "2017-01-03")) %>%
385 | group_by(date) %>%
386 | summarise(n = n()) %>%
387 | arrange(date)
388 |
389 | show_query(q)
390 | #> <SQL>
391 | #> SELECT "date", count(*) AS "n"
392 | #> FROM "my_table_name"
393 | #> WHERE ("date" BETWEEN '2017-01-01' AND '2017-01-03')
394 | #> GROUP BY "date"
395 | #> ORDER BY "date"
396 |
397 | # Send the query and get its result on R
398 | df <- q %>% collect
399 | df
400 | #> # A tibble: 3 x 2
401 | #> date n
402 | #> <date> <int>
403 | #> 1 2017-01-01 123456
404 | #> 2 2017-01-02 7891011
405 | #> 3 2017-01-03 12131415You can install the dplyr.teradata package from CRAN.
410 |install.packages("dplyr.teradata")You can also install the development version of the package from GitHub.
412 |install.packages("devtools") # if you have not installed "devtools" package
413 | devtools::install_github("hoxo-m/dplyr.teradata")The source code for dplyr.teradata package is available on GitHub at
415 |The package provides a Teradata backend for dplyr. It makes it possible to build SQL for Teradata Database in the same way as manipulating data frames with the dplyr package. It also can send the queries and then receive its results on R.
422 |Therefore, you can complete data analysis with Teradata only on R. It means that you are freed from troublesome switching of tools and switching thoughts that cause mistakes.
423 |The package uses the odbc package to connect database and the dbplyr package to build SQL.
427 |First, you need to establish an ODBC connection to Teradata. See:
428 |# Establish a connection to Teradata
432 | con <- dbConnect(odbc(),
433 | driver = "{Teradata Driver}", DBCName = "host_name_or_IP_address",
434 | uid = "user_name", pwd = "*****")Second, you need to specify a table to build SQL. See:
436 |To specify a table, you can use tbl():
# Getting table
441 | my_table <- tbl(con, "my_table_name")
442 |
443 | # Getting table in schema
444 | my_table <- tbl(con, in_schema("my_schema", "my_table_name"))Third, you build queries. It can do in the same way as manipulating data frames with dplyr:
446 |For example, you can use follows:
450 |mutate() adds new columns that are functions of existing columns.select() picks columns based on their names.filter() picks rows based on their values.summarise() reduces multiple values down to a single summary.arrange() changes the ordering of the rows.# Build a query
458 | q <- my_table %>%
459 | filter(between(date, "2017-01-01", "2017-01-03")) %>%
460 | group_by(date) %>%
461 | summarise(n = n()) %>%
462 | arrange(date)n() is a function in dplyr to return the number of rows in the current group but here it will be translated to count(*) as a SQL function.
If you want to show built queries, use show_query():
show_query(q)
466 | #> <SQL>
467 | #> SELECT "date", count(*) AS "n"
468 | #> FROM "my_table_name"
469 | #> WHERE ("date" BETWEEN '2017-01-01' AND '2017-01-03')
470 | #> GROUP BY "date"
471 | #> ORDER BY "date"Finally, you send built queries and get its results on R using collect().
# Send the query and get its result on R
474 | df <- q %>% collect
475 | df
476 | #> # A tibble: 3 x 2
477 | #> date n
478 | #> <date> <int>
479 | #> 1 2017-01-01 123456
480 | #> 2 2017-01-02 7891011
481 | #> 3 2017-01-03 12131415The package mainly use dbplyr to translate manipulations into queries.
486 |Translatable functions are the available functions in manipulations that it can translate into SQL functions.
487 |For instance, n() is translated to count(*) in the above example.
To know translatable functions for Teradata, refer the following:
489 |Here, we introduce the special translatable functions that it becomes available by dplyr.teradata.
493 |Teradata does not have the boolean data type. So when you use boolean, you need to write some complex statements. The package has several functions to treat it briefly.
496 |bool_to_int transforms boolean to integer.
mutate(is_positive = bool_to_int(x > 0L))#> <SQL> CASE WHEN (`x` > 0) THEN 1 WHEN NOT(`x` > 0) THEN 0 END
499 | count_if() or n_if() counts a number of rows satisfying a condition.
summarize(n = count_if(x > 0L))#> <SQL> SUM(CASE WHEN (`x` > 0) THEN 1 WHEN NOT(`x` > 0) THEN 0 END)
502 | to_timestamp()When your tables has some columns stored UNIX time and you want to convert it to timestamp, you need to write complex SQL.
506 |to_timestamp() is a translatable function that makes it easy.
mutate(ts = to_timestamp(unixtime_column))Such as above manipulation is translated into SQL like following:
509 |#> <SQL> CAST(DATE '1970-01-01' + (`unixtime_column` / 86400) AS TIMESTAMP(0)) + (`unixtime_column` MOD 86400) * (INTERVAL '00:00:01' HOUR TO SECOND)
510 | cut()cut() is very useful function that you can use in base R.
For example, you want to cut values of x into three parts of ranges by break points 2 and 4:
x <- 1:6
516 | breaks <- c(0, 2, 4, 6)
517 | cut(x, breaks)
518 | #> [1] (0,2] (0,2] (2,4] (2,4] (4,6] (4,6]
519 | #> Levels: (0,2] (2,4] (4,6]dplyr.teradata has a translatable function similar to this:
521 |breaks = c(0, 2, 4, 6)
522 | mutate(y = cut(x, breaks))In the result, it is translated to a CASE WHEN statement as follows:
#> <SQL> CASE
525 | #> WHEN x > 0 AND x <= 2 THEN '(0,2]'
526 | #> WHEN x > 2 AND x <= 4 THEN '(2,4]'
527 | #> WHEN x > 4 AND x <= 6 THEN '(4,6]'
528 | #> ELSE NULL
529 | #> END
530 | Arguments of base cut() are also available:
breaks = c(0, 2, 4, 6)
532 | mutate(y = cut(x, breaks, labels = "-", include.lowest = TRUE))#> <SQL> CASE
534 | #> WHEN x >= 0 AND x <= 2 THEN '0-2'
535 | #> WHEN x > 2 AND x <= 4 THEN '3-4'
536 | #> WHEN x > 4 AND x <= 6 THEN '5-6'
537 | #> ELSE NULL
538 | #> END
539 | blob_to_string()The blob object from databases sometimes prevents manipulations with dplyr.
You might want to convert them to string.
547 |blob_to_string() is a function to make it easy:
x <- blob::as_blob("Good morning")
549 | x
550 | #> <blob[1]>
551 | #> [1] blob[12 B]
552 |
553 | # print raw data in blob
554 | x[[1]]
555 | #> [1] 47 6f 6f 64 20 6d 6f 72 6e 69 6e 67
556 |
557 | blob_to_string(x)
558 | #> [1] "476f6f64206d6f726e696e67"