These functions mimic their R counterparts except that they generate
code that gets remotely executed in a database engine:
get,
assign,
exists,
remove,
objects, and
names.
# S4 method for OraConnection,character
dbReadTable(conn, name, schema = NULL,
row.names = NULL, sparse = FALSE, ...)
# S4 method for OraConnection,character,data.frame
dbWriteTable(conn, name, value,
row.names = FALSE, overwrite = FALSE, append = FALSE, ora.number = TRUE,
schema = NULL, date = FALSE, sparse = FALSE, ...)
# S4 method for OraConnection,character
dbExistsTable(conn, name, schema = NULL, ...)
# S4 method for OraConnection,character
dbRemoveTable(conn, name, purge = FALSE,
schema = NULL, ...)
# S4 method for OraConnection
dbListTables(conn, schema = NULL, all = FALSE, full = FALSE, ...)
# S4 method for OraConnection,character
dbListFields(conn, name, schema = NULL, ...)A data.frame in the case of dbReadTable;
a vector in the case of dbListTables and
dbListFields;
a logical in the case of dbExistsTable indicating
whether the table exists;
otherwise TRUE when the operation was successful or an
exception.
An OraConnection database connection object.
A case-sensitive character string specifying a table name.
A case-sensitive character string specifying a schema name (or a
vector of character strings for dbListTables).
A boolean flag to indicate whether to use date or DateTimep. By default, DateTime will be used instead of timestamp.
In the case of dbReadTable, this argument can be a string, an
index or a logical vector specifying the column in the DBMS table to
be used as row.names in the output data.frame (a NULL
specifies that no column should be used as row.names in the
output). The default is NULL.
In the case of dbWriteTable, this argument should be a logical
value specifying whether the row.names should be output to the
output DBMS table; if TRUE, an extra column whose name is
"row.names" will be added to the output. The default is
FALSE.
A data.frame containing the data to write to a table. (See
Details section for supported column types.)
A logical value specifying whether to overwrite an existing table
or not. The default is FALSE.
A logical value specifying whether to append to an existing table
in the DBMS. The default is FALSE.
A logical value specifying whether to create a table with Oracle
NUMBER or BINARY_DOUBLE columns while writing numeric
data. Specify TRUE to create a table with Oracle NUMBER
values or specify FALSE to create a table with Oracle
BINARY_DOUBLE values. The default value is TRUE.
Specify FALSE if one or more of the numeric data values are
NaN.
A logical value specifying whether to add the PURGE option to the
SQL DROP TABLE statement.
A logical value specifying whether to look at all schemas.
A logical value specifying whether to generate schema names. When argument
all is TRUE, the output is a vector containing schema
names followed by the table names. Using matrix(..., ncol = 2)
on the output produces a matrix where each row corresponds to a
table and the columns represent the schema names and table names
respectively.
A logical indicating whether to use sparseVector method from Matrix
library to construct sparse vectors returned by Oracle database. When
TRUE, sparse vectors are constructed using sparseVector method of Matrix
package. When FALSE, dense vector is returned and one can use any of the
R methods/packages to transform to sparse format. For dbWriteTable,
specifying sparse=TRUE will create the vector column in the database
as a sparse vector type, otherwise a dense vector type
is created.
currently unused.
Table, schema, and column names are case sensitive, e.g., table
names ABC and abc are not the same. All database schema
object names should not include double quotes as they are enclosed in
double quotes when the corresponding SQL statement is generated.
The following attributes are used for correctly mapping BLOB, CLOB, NCLOB,
NCHAR, VARCHAR2, NVARCHAR2, CHAR, TIMESTAMP WITH TIME ZONE, TIMESTAMP WITH
LOCAL TIME ZONE and VECTOR columns in dbWriteTable:
1) Attribute Name: ora.type
This attribute indicates the type of the underlying column and can be
"CLOB", "BLOB", "CHAR", "VARCHAR2", "RAW", or "VECTOR". The user can specify
TIMESTAMP, DATE, TIMESTAMP WITH TIME ZONE or any other column types
supported by Oracle Database. ROracle does not parse the value; it is
validated by the database. The user can provide one of the following
values for ora.type: CLOB, BLOB, CHAR, TIMESTAMP WITH TIME
ZONE, TIMESTAMP WITH LOCAL TIME ZONE, VECTOR and fractional_seconds_precision.
2) Attribute Name: ora.encoding
When UTF-8 is specified, the database uses NCLOB, NCHAR or NVARCHAR based on
ora.type.
3) Attribute Name: ora.maxlength
One can specify the maximum length of CHAR, VARCHAR, NCHAR, NVARCHAR2, or
RAW columns. For other data types, ora.maxlength does not
apply and is ignored. The following default values are used for
certain data types when ora.maxlength is not specified.
CHAR 2000
NCHAR 1000
VARCHAR2 4000
NVARCHAR2 2000
RAW 2000
4) Attribute Name: ora.format
For vector data type when ora.maxlength and ora.format are
not specified flex dimension and format are used.
Type VECTOR(*) column info indicates flex format and length NA denotes flex dimension.
5) Attribute Name: ora.fractional_seconds_precision
One can specify the fractional part of the SECOND datetime field of
TIMESTAMP, TIMESTAMP WITH TIME ZONE and TIMESTAMP WITH LOCAL TIME ZONE
columns. It can be a number in the range 0 to 9. The default value is 6.
ROracle methods such as dbReadTable, dbGetQuery,
fetch, and dbWriteTable use the following mapping
between R and Oracle data types:
logical and integer map to Oracle INTEGER
numeric maps to Oracle NUMBER if argument
ora.number is TRUE or Oracle BINARY_DOUBLE if
FALSE
character maps to Oracle CLOB if attribute
ora.type is "CLOB" or Oracle NCLOB if attribute
ora.type is "CLOB" and ora.encoding is "UTF-8"
or Oracle CHAR(ora.maxlength) if attribute ora.type is
"CHAR" or Oracle NCHAR(ora.maxlength) if attribute
ora.type is "CHAR" and ora.encoding is "UTF-8"
or Oracle NVARCHAR2(ora.maxlength) if attribute ora.encoding
is "UTF-8" or Oracle VARCHAR2(ora.maxlength)
Date and POSIXct map to Oracle DATE
ROracle - the ROracle package
R - the R application
POSIXct maps to Oracle
TIMESTAMP WITH TIME ZONE(ora.fractional_seconds_precision) if
attribute ora.type is "TIMESTAMP WITH TIME ZONE" or Oracle
TIMESTAMP WITH LOCAL TIME ZONE(ora.fractional_seconds_precision) if
attribute ora.type is "TIMESTAMP WITH LOCAL TIME ZONE" or
Oracle TIMESTAMP(ora.fractional_seconds_precision) and if
Date is FALSE
difftime maps to Oracle INTERVAL DAY TO SECOND
list of raw vectors map to Oracle BLOB if
attribute ora.type is "BLOB" or Oracle
RAW(ora.maxlength)
list of raw, numeric, character,
integer vectors map to Oracle VECTOR if
attribute ora.type is "VECTOR" or Oracle
RAW(ora.maxlength) CHAR(ora.maxlength), NUMBER(ora.maxlength)
other R types such as factor are converted to
character
ROracle returns values from database columns that are of data type: date, time stamp, time stamp with time zone and time stamp with local time zone data types in R's POSIXct format. POSIXct refers to a time that is internally stored as the number of seconds since the start of 1970 in UTC. Number of seconds are exchanged from R and ROracle driver in floating point double format. In POSIXct representation R uses the TZ environment variable or maps the OS time zone environment variable to its own, therefore the date will be displayed in this time zone format.
One can insert data into columns of the four data types listed above using a string with the correct format or POSIXct representation. String data is passed to the database directly and ROracle relies on databse to convert it to date time representation. ROracle driver converts the POSIXct representation to a string representation using the format "%Y-%m-%d %H:%M:%OS6" in a data frame that is used for DML operations. Data in this format corresponds to NLS_TIMESTAMP_TZ_FORMAT "YYYY-MM-DD HH24:MI:SSXFF" and is converted to SQLT_TIMESTAMP_LTZ to be bound to the Oracle database. An intermediate class "datetime" is created that represents character data to the ROracle driver internally.
Columns having a date and time stamp data type are fetched by ROracle using the SQLT_TIMESTAMP data type. Columns having a time stamp with time zone or a time stamp with local time zone data types are fetched using SQLT_TIMESTAMP_LTZ data type. Columns of data type time stamp with local time zone undergo conversion to the session time zone that the R application runs in, therefore setting the time zone environment TZ in R will affect the data values in this column. ROracle driver maps the TZ environment variable to the session time zone and issues an alter DDL to set the session time zone when the connection is made to the database.
To fetch data from columns with a timestamp with time zone or a timestamp with local time zone, the client and server must have the same time zone data file else an error will be reported.
When these data types are selected from the database, they are converted to string representation using the NLS_TIMESTAMP_TZ_FORMAT "YYYY-MM-DD HH24:MI:SSXFF" that corresponds to "%Y-%m-%d %H:%M:%OS6" in R. An intermediate class "datetime" is created to represent this character data in ROracle driver. ROracle driver then converts it to POSIXct using the as.POSIXct() function. An R application sees the data in POSIXct form in the data frame.
R session time zone:
R has the concept of a time zone in which the R engine operates. The time
zone can be set to a string such as 'PST8PDT', 'America/Los_Angeles' and so on.
These strings are self-explanatory and specify the time zone in which the
session is operating.
The R session time zone can be set in one of two ways:
1. By entering the following on the Linux or Unix command line before starting
R:
setenv TZ = America/Los_Angeles on Linux/UNIX
NOTE: Do not use this option on Windows as it does not allow one to
set Oracle compatible timezone names for the environment variable TZ.
2. By entering the following at the R prompt:
Sys.setenv(TZ = "PST8PDT") We recommend using the option 2 as the R script works without any
porting issues on Linux/Unix as well as Windows. Option 2 also allows you
to specify Oracle compatible timezone names even on Windows.
The R session time zone determines the time zone for all POSIXct time
zone unqualified date-time types. It is also the time zone to which all
qualified date-time types are converted when they are displayed by R.
The following example demonstrates this.
Sys.setenv(TZ = "PST8PDT")
dt <- c(as.POSIXct("2010/3/13", tz = "PST8PDT"),
as.POSIXct("2010/3/13 3:47:30.123456", tz = "PST8PDT"),
as.POSIXct("2010/3/22", tz = "PST8PDT"),
as.POSIXct("2010/3/22 7:02:30", tz = "PST8PDT"),
as.POSIXct("2010/3/13"),
as.POSIXct("2010/3/13 3:47:30.123456"),
as.POSIXct("2010/3/22"),
as.POSIXct("2010/3/22 7:02:30"))
dt
[1] "2010-03-13 00:00:00.000000 PST" "2010-03-13 03:47:30.123456 PST"
[3] "2010-03-22 00:00:00.000000 PDT" "2010-03-22 07:02:30.000000 PDT"
[5] "2010-03-13 00:00:00.000000 PST" "2010-03-13 03:47:30.123456 PST"
[7] "2010-03-22 00:00:00.000000 PDT" "2010-03-22 07:02:30.000000 PDT"
Note that the unqualified timestamps are also assumed to be in the R's
session time zone when they are displayed by R. Of course, R is also smart
enough to make the determination of whether the time falls into PST or PDT
based on when US Daylight savings begins, and displays PST or PDT
accordingly.
The following example makes this more obvious.
> Sys.setenv(TZ = "EST5EDT")
> dt <- c(as.POSIXct("2010/3/13", tz = "PST8PDT"),
+ as.POSIXct("2010/3/13 3:47:30.123456", tz = "PST8PDT"),
+ as.POSIXct("2010/3/22", tz = "PST8PDT"),
+ as.POSIXct("2010/3/22 7:02:30", tz = "PST8PDT"),
+ as.POSIXct("2010/3/13"),
+ as.POSIXct("2010/3/13 3:47:30.123456"),
+ as.POSIXct("2010/3/22"),
+ as.POSIXct("2010/3/22 7:02:30"))
> dt
[1] "2010-03-13 03:00:00.000000 EST" "2010-03-13 06:47:30.123456 EST"
[3] "2010-03-22 03:00:00.000000 EDT" "2010-03-22 10:02:30.000000 EDT"
[5] "2010-03-13 00:00:00.000000 EST" "2010-03-13 03:47:30.123456 EST"
[7] "2010-03-22 00:00:00.000000 EDT" "2010-03-22 07:02:30.000000 EDT"
Note that all the time zone unqualified timestamps are assumed to be in
the session time zone. However, even the time zone qualified timestamps
are converted to session time zone and displayed. Note that all the
values are displayed by R in the R session's time zone (with the
timezone name also modified to EST or EDT to account for
daylight savings as applicable). Refer to Date-Time Classes at
http://stat.ethz.ch/R-manual/R-devel/library/base/html/DateTimeClasses.html
and timezones at:
http://stat.ethz.ch/R-manual/R-devel/library/base/html/timezones.html
for details on how R handles dates and times and time zones)
Let's take an example where we use a longer time zone name
(often referred to as an 'Olson Name') as opposed to an abbreviation.
> Sys.setenv(TZ = "America/Los_Angeles")
> dt <- c(as.POSIXct("2010/3/13", tz = "PST8PDT"),
+ as.POSIXct("2010/3/13 3:47:30.123456", tz = "PST8PDT"),
+ as.POSIXct("2010/3/22", tz = "PST8PDT"),
+ as.POSIXct("2010/3/22 7:02:30", tz = "PST8PDT"),
+ as.POSIXct("2010/3/13"),
+ as.POSIXct("2010/3/13 3:47:30.123456"),
+ as.POSIXct("2010/3/22"),
+ as.POSIXct("2010/3/22 7:02:30"))
> dt
[1] "2010-03-13 00:00:00.000000 PST" "2010-03-13 03:47:30.123456 PST"
[3] "2010-03-22 00:00:00.000000 PDT" "2010-03-22 07:02:30.000000 PDT"
[5] "2010-03-13 00:00:00.000000 PST" "2010-03-13 03:47:30.123456 PST"
[7] "2010-03-22 00:00:00.000000 PDT" "2010-03-22 07:02:30.000000 PDT"
Note that in such a case, R doesn't use the long name when the
values are displayed, but instead still displays the values using
the abbreviations "PST" and "PDT". This is significant because Oracle
doesn't necessarily like these abbreviations. For example, an Oracle
databse doesn't recognize "PDT" as a valid time zone. See "R Time zone
and Oracle session time zone" for details on valid time zones.
The example below shows the effect of changing the time zone in R environment:
R> Sys.timezone()
[1] "PST8PDT"
# Selecting data and displaying it
res <- dbGetQuery(con, selStr)
R> res[,1]
[1] 1 2 3 4 5 6
R> res[,2]
[1] "2012-06-05 00:00:00 PDT" "2012-01-05 07:15:02 PST"
"2012-01-05 00:00:00 PST" "2011-01-05 00:00:00 PST"
[5] "2013-01-05 00:00:00 PST" "2020-01-05 00:00:00 PST"
R> res[,3]
[1] "2012-06-05 00:00:00 PDT" "2012-01-05 07:15:03 PST"
"2012-01-05 00:00:00 PST" "2011-01-05 00:00:00 PST"
[5] "2013-01-05 00:00:00 PST" "2020-01-05 00:00:00 PST"
R> res[,4]
[1] "2012-06-05 00:00:00 PDT" "2012-01-05 07:15:03 PST"
"2012-01-05 00:00:00 PST" "2011-01-05 00:00:00 PST"
[5] "2013-01-05 00:00:00 PST" "2020-01-05 00:00:00 PST"
R> res[,5]
[1] "2012-06-05 00:00:00 PDT" "2012-01-05 07:15:03 PST"
"2012-01-05 00:00:00 PST" "2011-01-05 00:00:00 PST"
[5] "2013-01-05 00:00:00 PST" "2020-01-05 00:00:00 PST"
R> Sys.setenv(TZ='EST5EDT')
R> res[,1]
[1] 1 2 3 4 5 6
R> res[,2]
[1] "2012-06-05 03:00:00 EDT" "2012-01-05 10:15:02 EST"
"2012-01-05 03:00:00 EST" "2011-01-05 03:00:00 EST"
[5] "2013-01-05 03:00:00 EST" "2020-01-05 03:00:00 EST"
R> res[,3]
[1] "2012-06-05 03:00:00 EDT" "2012-01-05 10:15:03 EST"
"2012-01-05 03:00:00 EST" "2011-01-05 03:00:00 EST"
[5] "2013-01-05 03:00:00 EST" "2020-01-05 03:00:00 EST"
R> res[,4]
[1] "2012-06-05 03:00:00 EDT" "2012-01-05 10:15:03 EST"
"2012-01-05 03:00:00 EST" "2011-01-05 03:00:00 EST"
[5] "2013-01-05 03:00:00 EST" "2020-01-05 03:00:00 EST"
R> res[,5]
[1] "2012-06-05 03:00:00 EDT" "2012-01-05 10:15:03 EST"
"2012-01-05 03:00:00 EST" "2011-01-05 03:00:00 EST"
[5] "2013-01-05 03:00:00 EST" "2020-01-05 03:00:00 EST"
Also dbWriteTable always auto commits a current transaction as
well as the data it inserts, i.e. it acts as a DDL statement even if
appends rows to an already existing table.
For the Oracle Database documentation see https://docs.oracle.com/en/. For Datetime Data Types and Time Zone Support in Oracle see https://docs.oracle.com/cd/E11882_01/server.112/e10729/ch4datetime.htm.
Oracle,
dbDriver,
dbConnect,
dbSendQuery,
dbGetQuery,
fetch,
dbCommit,
dbGetInfo.