Working with external tables in RDS for Oracle
Oracle external tables are tables with data that is not
in the database. Instead, the data is in external files that the database can
access. By using external tables, you can access data without loading it into
the database. For more information about external tables, see Managing external tables
With Amazon RDS, you can store external table files in directory objects. You can create a directory object, or you can use one that is predefined in the Oracle database, such as the DATA_PUMP_DIR directory. For information about creating directory objects, see Creating and dropping directories in the main data storage space. You can query the ALL_DIRECTORIES view to list the directory objects for your Amazon RDS Oracle DB instance.
Note
Directory objects point to the main data storage space (Amazon EBS volume) used by your instance. The space used—along with data files, redo logs, audit, trace, and other files—counts against allocated storage.
You can move an external data file from one Oracle database to another by
using the
DBMS_FILE_TRANSFERDBMS_FILE_TRANSFER, see Importing using Oracle Data Pump.
After you move the external data file, you can create an external table with
it. The following example creates an external table that uses the
emp_xt_file1.txt file in the USER_DIR1 directory.
CREATE TABLE emp_xt ( emp_id NUMBER, first_name VARCHAR2(50), last_name VARCHAR2(50), user_name VARCHAR2(20) ) ORGANIZATION EXTERNAL ( TYPE ORACLE_LOADER DEFAULT DIRECTORY USER_DIR1 ACCESS PARAMETERS ( RECORDS DELIMITED BY NEWLINE FIELDS TERMINATED BY ',' MISSING FIELD VALUES ARE NULL (emp_id,first_name,last_name,user_name) ) LOCATION ('emp_xt_file1.txt') ) PARALLEL REJECT LIMIT UNLIMITED;
Suppose that you want to move data that is in an Amazon RDS Oracle DB instance into an
external data file. In this case, you can populate the external data file by
creating an external table and selecting the data from the table in the
database. For example, the following SQL statement creates the
orders_xt external table by querying the orders
table in the database.
CREATE TABLE orders_xt ORGANIZATION EXTERNAL ( TYPE ORACLE_DATAPUMP DEFAULT DIRECTORY DATA_PUMP_DIR LOCATION ('orders_xt.dmp') ) AS SELECT * FROM orders;
In this example, the data is populated in the orders_xt.dmp file
in the DATA_PUMP_DIR directory.