Example Upsert - Parallel Data Pump

Teradata Parallel Data Pump Reference

Product
Parallel Data Pump
Release Number
16.10
Published
May 2017
Language
English (United States)
Last Update
2018-05-22
dita:mapPath
tqa1488824663174.ditamap
dita:ditavalPath
Audience_PDF_include.ditaval
dita:id
B035-3021
lifecycle
previous
Product Category
Teradata Tools and Utilities

Each record in the following example contains the value of the primary index column (EmpNo) of a row of the Employee table whose PhoneNo column is to be assigned a new phone number from field Fone.

When the UPDATE fails, the INSERT statement is activated and Teradata TPump enters the upsert mode. In this case, each record contains the primary index value (EmpNum) of a row that is to be inserted successively into the Employee table whose columns are EmpNo and PhoneNo.

.BEGINLOAD SESSION number;
.LAYOUT Layoutname;
.FIELD EmpNum 1 INTEGER;
.FIELD Fone * (CHAR (10));
.DML LABEL DMLlabelname
DO INSERT FOR MISSING UPDATE ROWS;
UPDATE Employee SET PhoneNo = :Fone WHERE EmpNo = :EmpNum;
INSERT Employee (EmpNo, PhoneNo) VALUES (:EmpNum, :Fone);
.IMPORT INFILE Infilename LAYOUT Layoutname APPLY DMLlabelname;
.END LOAD;

The scope of a DML command (and its label) terminates at the first following command of any kind or at the end of the file containing the DML statements, whichever occurs first.

The SQL EXECUTE command must be between the BEGIN LOAD command and END LOAD command.

For IMPORT tasks, up to seven distinct error treatment options for one DML command may be specified. For example:

.DML LABEL COMPLEX
IGNORE DUPLICATE INSERT ROWS
MARK   DUPLICATE UPDATE ROWS
IGNORE MISSING UPDATE ROWS
MARK   MISSING DELETE ROWS
DO INSERT FOR MISSING UPDATE ROWS;

It is valid to specify that missing update rows be both marked and treated as INSERTs or, as in the example, both ignored and treated as INSERTs.

If Teradata TPump encounters any of the following:
  • no DML command in an IMPORT task,
  • DML statements outside the scope of a DML command in an IMPORT task, or
  • a DML command with no DML statements in an IMPORT task,

it writes a diagnostic message to the primary output destination for the system, terminates the Teradata TPump task, and returns to the main Teradata TPump control module with a conventional nonzero return code. The error can be corrected and resubmitted to the Teradata TPump task.

The DML commands (with their following DML statements) must appear between the appropriate BEGIN LOAD command and the IMPORT commands that refer to them. When the END LOAD command is encountered, the sequence of DML commands and DML statements is forgotten. The DML command cannot be shared by multiple BEGIN LOAD statements. The DML statements are described in the following sections.

The maximum number of DML commands that can be used in a single Teradata TPump task is 128. If an excessive number of DML commands and statements are sent to Teradata Database, an error message is logged, stating that there are too many DML steps for one Teradata TPump job.