Oracle9i Database Utilities Release 2 (9.2) Part Number A96652-01 |
|
This chapter describes the command-line parameters used to invoke SQL*Loader. The following topics are discussed:
When you invoke SQL*Loader, you can specify certain parameters to establish session characteristics. Parameters can be entered in any order, optionally separated by commas. You specify values for parameters, or in some cases, you can accept the default without entering a value.
For example:
SQLLDR CONTROL=foo.ctl, LOG=bar.log, BAD=baz.bad, DATA=etc.dat USERID=scott/tiger, ERRORS=999, LOAD=2000, DISCARD=toss.dis, DISCARDMAX=5
If you invoke SQL*Loader without specifying any parameters, SQL*Loader displays a help screen similar to the following. It lists the available parameters and their default values.
sqlldr ... SQL*Loader: Release 9.2.0.1.0 - Production on Wed Feb 27 12:06:17 2002 (c) Copyright 2002 Oracle Corporation. All rights reserved. Usage: SQLLDR keyword=value [,keyword=value,...] Valid Keywords: userid -- ORACLE username/password control -- Control file name log -- Log file name bad -- Bad file name data -- Data file name discard -- Discard file name discardmax -- Number of discards to allow (Default all) skip -- Number of logical records to skip (Default 0) load -- Number of logical records to load (Default all) errors -- Number of errors to allow (Default 50) rows -- Number of rows in conventional path bind array or between direct path data saves (Default: Conventional path 64, Direct path all) bindsize -- Size of conventional path bind array in bytes (Default 256000) silent -- Suppress messages during run (header,feedback,errors,discards,partitions) direct -- use direct path (Default FALSE) parfile -- parameter file: name of file that contains parameter specifications parallel -- do parallel load (Default FALSE) file -- File to allocate extents from skip_unusable_indexes -- disallow/allow unusable indexes or index partitions (Default FALSE) skip_index_maintenance -- do not maintain indexes, mark affected indexes as unusable (Default FALSE) readsize -- Size of Read buffer (Default 1048576) external_table -- use external table for load; NOT_USED, GENERATE_ONLY, EXECUTE (Default NOT_ USED) columnarrayrows -- Number of rows for direct path column array (Default 5000) streamsize -- Size of direct path stream buffer in bytes (Default 256000) multithreading -- use multithreading in direct path resumable -- enable or disable resumable for current session (Default FALSE) resumable_name -- text string to help identify resumable statement resumable_timeout -- wait time (in seconds) for RESUMABLE (Default 7200) date_cache -- size (in entries) of date conversion cache (Default 1000) PLEASE NOTE: Command-line parameters may be specified either by position or by keywords. An example of the former case is 'sqlldr scott/tiger foo'; an example of the latter is 'sqlldr control=foo userid=scott/tiger'. One may specify parameters by position before but not after parameters specified by keywords. For example,'sqlldr scott/tiger control=foo logfile=log' is allowed, but 'sqlldr scott/tiger control=foo log' is not, even though the position of the parameter 'log' is correct.
See Also:
Command-Line Parameters for descriptions of all the command-line parameters |
If the length of the command line exceeds the size of the maximum command line on your system, you can put some command-line parameters in the control file. See OPTIONS Clause for information on how to do this.
They can also be specified in a separate file specified by the PARFILE
parameter. These alternative methods are useful for specifying parameters whose values seldom change. Parameters specified in this manner can be overridden from the command line.
See Also:
|
This section describes each SQL*Loader command-line parameter. The defaults and maximum values listed for these parameters are for UNIX-based systems. They may be different on your operating system. Refer to your Oracle operating system-specific documentation for more information.
Default: The name of the datafile, with an extension of .bad
.
BAD
specifies the name of the bad file created by SQL*Loader to store records that cause errors during insert or that are improperly formatted. If a filename is not specified, the default is used.
A bad file filename specified on the command line becomes the bad file associated with the first INFILE
statement in the control file. If the bad file filename was also specified in the control file, the command-line value overrides it.
See Also:
Specifying the Bad File for information about the format of bad files |
Default: To see the default value for this parameter, invoke SQL*Loader without any parameters, as described in Invoking SQL*Loader.
BINDSIZE
specifies the maximum size (bytes) of the bind array. The size of the bind array given by BINDSIZE
overrides the default size (which is system dependent) and any size determined by ROWS.
Default: To see the default value for this parameter, invoke SQL*Loader without any parameters, as described in Invoking SQL*Loader.
Specifies the number of rows to allocate for direct path column arrays. The value for this parameter is not calculated by SQL*Loader. You must either specify it or accept the default.
Default: none
CONTROL
specifies the name of the SQL*Loader control file that describes how to load data. If a file extension or file type is not specified, it defaults to .ctl
. If the filename is omitted, SQL*Loader prompts you for it.
If the name of your SQL*Loader control file contains special characters, your operating system may require that they be preceded by an escape character. Also, if your operating system uses backslashes in its file system paths, you may need to use multiple escape characters or to enclose the path in quotation marks. See your Oracle operating system-specific documentation for more information.
See Also:
Chapter 5 for a detailed description of the SQL*Loader control file |
Default: The name of the control file, with an extension of .dat
.
DATA
specifies the name of the datafile containing the data to be loaded. If you do not specify a file extension or file type, the default is .dat.
If you specify a datafile on the command line and also specify datafiles in the control file with INFILE,
the data specified on the command line is processed first. The first datafile specified in the control file is ignored. All other datafiles specified in the control file are processed.
If you specify a file processing option when loading data from the control file, a warning message will be issued.
Default: Enabled (for 1000
elements). To completely disable the date cache feature, set it to 0
.
DATE_CACHE
specifies the date cache size (in entries). For example, DATE_CACHE=5000
specifies that each date cache created can contain a maximum of 5000 unique date entries. Every table has its own date cache, if one is needed. A date cache is created only if at least one date or timestamp value is loaded that requires datatype conversion in order to be stored in the table.
The date cache feature is only available for direct path loads. It is enabled by default. The default date cache size is 1000 elements. If the default size is used and the number of unique input values loaded exceeds 1000, then the date cache feature is automatically disabled for that table. However, if you override the default and specify a nonzero date cache size and that size is exceeded, then the cache is not disabled.
You can use the date cache statistics (entries, hits, and misses) contained in the log file to tune the size of the cache for future similar loads.
Default: false
DIRECT
specifies the data path, that is, the load method to use, either conventional path or direct path. A value of true
specifies a direct path load. A value of false
specifies a conventional path load.
Default: The name of the datafile, with an extension of .dsc
.
DISCARD
specifies a discard file (optional) to be created by SQL*Loader to store records that are neither inserted into a table nor rejected.
A discard file filename specified on the command line becomes the discard file associated with the first INFILE
statement in the control file. If the discard file filename is specified also in the control file, the command-line value overrides it.
See Also:
Discarded and Rejected Records for information about the format of discard files |
Default: ALL
DISCARDMAX
specifies the number of discard records to allow before data loading is terminated. To stop on the first discarded record, specify one (1).
Default: To see the default value for this parameter, invoke SQL*Loader without any parameters, as described in Invoking SQL*Loader.
ERRORS
specifies the maximum number of insert errors to allow. If the number of errors exceeds the value specified for ERRORS
, then SQL*Loader terminates the load. To permit no errors at all, set ERRORS=0.
To specify that all errors be allowed, use a very high number.
On a single-table load, SQL*Loader terminates the load when errors exceed this error limit. Any data inserted up that point, however, is committed.
SQL*Loader maintains the consistency of records across all tables. Therefore, multitable loads do not terminate immediately if errors exceed the error limit. When SQL*Loader encounters the maximum number of errors for a multitable load, it continues to load rows to ensure that valid rows previously loaded into tables are loaded into all tables and/or rejected rows filtered out of all tables.
In all cases, SQL*Loader writes erroneous records to the bad file.
Default: NOT_USED
EXTERNAL_TABLE
instructs SQL*Loader whether or not to load data using the external tables option. There are three possible values:
NOT_USED
--the default value. It means the load is performed using either conventional or direct path mode.GENERATE_ONLY
--places all the SQL statements needed to do the load using external tables, as described in the control file, in the SQL*Loader log file. These SQL statements can be edited and customized. The actual load can be done later without the use of SQL*Loader by executing these statements in SQL*Plus. See Log File Created When EXTERNAL_TABLE=GENERATE_ONLY for an example of what this log file would look like.EXECUTE
--attempts to execute the SQL statements that are needed to do the load using external tables. However, if any of the SQL statements returns an error, then the attempt to load stops. Statements are placed in the log file as they are executed. This means that if a SQL statement returns an error, then the remaining SQL statements required for the load will not be placed in the control file.Note that the external tables option uses directory objects in the database to indicate where all datafiles are stored and to indicate where output files, such as bad files and discard files, are created. You must have READ
access to the directory objects containing the datafiles, and you must have WRITE
access to the directory objects where the output files are created. If there are no existing directory objects for the location of a datafile or output file, SQL*Loader will generate the SQL statement to create one. Note that if the EXECUTE
option is specified, then you must have the CREATE
ANY
DIRECTORY
privilege.
When using a multitable load, SQL*Loader does the following:
INSERT
statement to load this table from an external table description of the data.INSERT
statement for every table in the control file.To see an example of this, run case study 5 (Case Study 5: Loading Data into Multiple Tables), but add the EXTERNAL_TABLE=GENERATE_ONLY
parameter. To guarantee unique names in the external table, SQL*Loader uses generated names for all fields. This is because the field names may not be unique across the different tables in the control file.
The following restrictions apply when you use the EXTERNAL_TABLE
qualifier:
TO_DATE
and TO_CHAR
to convert the Julian date format, as shown in the following example:
TO_CHAR(TO_DATE(:COL1, 'MM-DD-YYYY'), 'J')
Default: none
FILE
specifies the database file to allocate extents from. It is used only for parallel loads. By varying the value of the FILE
parameter for different SQL*Loader processes, data can be loaded onto a system with minimal disk contention.
Default: All records are loaded.
LOAD
specifies the maximum number of logical records to load (after skipping the specified number of records). No error occurs if fewer than the maximum number of records are found.
Default: The name of the control file, with an extension of .log
.
LOG
specifies the log file that SQL*Loader will create to store logging information about the loading process.
Default: true
on multiple-CPU systems, false
on single-CPU systems
This parameter is available only for direct path loads.
By default, the multithreading option is always enabled (set to true
) on multiple-CPU systems. In this case, the definition of a multiple-CPU system is a single system that has more than one CPU.
On single-CPU systems, multithreading is set to false
by default. To use multithreading between two single-CPU systems, you must enable multithreading; it will not be on by default. This will allow stream building on the client system to be done in parallel with stream loading on the server system.
Multithreading functionality is operating system-dependent. Not all operating systems support multithreading.
Default: false
PARALLEL
specifies whether direct loads can operate in multiple concurrent sessions to load data into the same table.
Default: none
PARFILE
specifies the name of a file that contains commonly used command-line parameters. For example, the command line could read:
sqlldr PARFILE=example.par
The parameter file could have the following contents:
USERID=scott/tiger CONTROL=example.ctl ERRORS=9999 LOG=example.log
Note: Although it is not usually important, on some systems it may be necessary to have no spaces around the equal sign (=) in the parameter specifications. |
Default: To see the default value for this parameter, invoke SQL*Loader without any parameters, as described in Invoking SQL*Loader.
The READSIZE
parameter is used only when reading data from datafiles. When reading records from a control file, a value of 64K is always used as the READSIZE
.
The READSIZE
parameter lets you specify (in bytes) the size of the read buffer, if you choose not to use the default. The maximum size allowed is 20MB for both direct path loads and conventional path loads.
In the conventional path method, the bind array is limited by the size of the read buffer. Therefore, the advantage of a larger read buffer is that more data can be read before a commit is required.
For example:
sqlldr scott/tiger CONTROL=ulcas1.ctl READSIZE=1000000
This example enables SQL*Loader to perform reads from the external datafile in chunks of 1,000,000 bytes before a commit is required.
Note: If the |
The READSIZE
parameter has no effect on LOBs. The size of the LOB read buffer is fixed at 64 KB.
Default: false
The RESUMABLE
parameter is used to enable and disable resumable space allocation. Because this parameter is disabled by default, you must set RESUMABLE=true
in order to use its associated parameters, RESUMABLE_NAME
and RESUMABLE_TIMEOUT
.
Default: 'User USERNAME (USERID), Session SESSIONID, Instance INSTANCEID'
The value for this parameter identifies the statement that is resumable. This value is a user-defined text string that is inserted in either the USER_RESUMABLE
or DBA_RESUMABLE
view to help you identify a specific resumable statement that has been suspended.
This parameter is ignored unless the RESUMABLE
parameter is set to true
to enable resumable space allocation.
Default: 7200
seconds (2 hours)
The value of the parameter specifies the time period during which an error must be fixed. If the error is not fixed within the timeout period, execution of the statement is aborted.
This parameter is ignored unless the RESUMABLE
parameter is set to true
to enable resumable space allocation.
Default: To see the default value for this parameter, invoke SQL*Loader without any parameters, as described in Invoking SQL*Loader.
Conventional path loads only: ROWS
specifies the number of rows in the bind array. See Bind Arrays and Conventional Path Loads.
Direct path loads only: ROWS
identifies the number of rows you want to read from the datafile before a data save. The default is to read all rows and save data once at the end of the load. See Using Data Saves to Protect Against Data Loss.
Because the direct load is optimized for performance, it uses buffers that are the same size and format as the system's I/O blocks. Only full buffers are written to the database, so the value of ROWS
is approximate.
When SQL*Loader begins, a header message similar to the following appears on the screen and is placed in the log file:
SQL*Loader: Release 9.2.0.1.0 - Production on Wed Feb 27 14:33:54 2002 (c) Copyright 2002 Oracle Corporation. All rights reserved.
As SQL*Loader executes, you also see feedback messages on the screen, for example:
Commit point reached - logical record count 20
SQL*Loader may also display data error messages like the following:
Record 4: Rejected - Error on table EMP ORA-00001: unique constraint <name> violated
You can suppress these messages by specifying SILENT
with one or more values.
For example, you can suppress the header and feedback messages that normally appear on the screen with the following command-line argument:
SILENT=(HEADER, FEEDBACK)
Use the appropriate values to suppress one or more of the following:
HEADER
- Suppresses the SQL*Loader header messages that normally appear on the screen. Header messages still appear in the log fileFEEDBACK
- Suppresses the "commit point reached" feedback messages that normally appear on the screenERRORS
- Suppresses the data error messages in the log file that occur when a record generates an Oracle error that causes it to be written to the bad file. A count of rejected records still appears.DISCARDS
- Suppresses the messages in the log file for each record written to the discard file.PARTITIONS
- Disables writing the per-partition statistics to the log file during a direct load of a partitioned table.ALL
- Implements all of the suppression values: HEADER,
FEEDBACK,
ERRORS,
DISCARDS,
and PARTITIONS.
Default: No records are skipped.
SKIP
specifies the number of logical records from the beginning of the file that should not be loaded.
This parameter continues loads that have been interrupted for some reason. It is used for all conventional loads, for single-table direct loads, and for multiple-table direct loads when the same number of records were loaded into each table. It is not used for multiple-table direct loads when a different number of records were loaded into each table.
Default: false
The SKIP_INDEX_MAINTENANCE
parameter stops index maintenance for direct path loads but does not apply to conventional path loads. It causes the index partitions that would have had index keys added to them instead to be marked Index Unusable because the index segment is inconsistent with respect to the data it indexes. Index segments that are not affected by the load retain the Index Unusable state they had prior to the load.
The SKIP_INDEX_MAINTENANCE
parameter:
PARALLEL
parameter) to do parallel loads on an object that has indexesPARTITION
parameter on the INTO TABLE
clause) to do a single partition load to a table that has global indexesDefault: false
The SKIP_UNUSABLE_INDEXES
parameter applies to both conventional and direct path loads.
SKIP_UNUSABLE_INDEXES=true
allows SQL*Loader to load a table with indexes that are in Index Unusable (IU) state prior to the beginning of the load. Indexes that are not in IU state at load time will be maintained by SQL*Loader. Indexes that are in IU state at load time will not be maintained but will remain in IU state at load completion.
However, indexes that are unique and marked IU are not allowed to skip index maintenance. This rule is enforced by DML operations, and enforced by the direct path load to be consistent with DML.
Load behavior with SKIP_UNUSABLE_INDEXES=false
differs slightly between conventional path loads and direct path loads:
Default: To see the default value for this parameter, invoke SQL*Loader without any parameters, as described in Invoking SQL*Loader.
Specifies the size, in bytes, for direct path streams.
Default: none
USERID
is used to provide your Oracle username/password.
If it is omitted, you are prompted for it. If only a slash is used, USERID
defaults to your operating system login.
If you connect as user SYS
, you must also specify AS SYSDBA
in the connect string. For example:
sqlldr \'SYS/password
AS SYSDBA\' foo.ctl
Oracle SQL*Loader provides the results of a SQL*Loader run immediately upon completion. Depending on the platform, SQL*Loader may report the outcome in a process exit code as well as recording the results in the log file. This Oracle SQL*Loader functionality allows for checking the outcome of a SQL*Loader invocation from the command line or script. Table 4-1 shows the exit codes for various results.
For UNIX, the exit codes are as follows:
EX_SUCC 0 EX_FAIL 1 EX_WARN 2 EX_FTL 3
For Windows NT, the exit codes are as follows:
EX_SUCC 0 EX_WARN 2 EX_FAIL 3 EX_FTL 4
If SQL*Loader returns any exit code other than zero, you should consult your system log files and SQL*Loader log files for more detailed diagnostic information.
In UNIX, you can check the exit code from the shell to determine the outcome of a load. For example, you could place the SQL*Loader command in a script and check the exit code within the script:
#!/bin/sh sqlldr scott/tiger control=ulcase1.ctl log=ulcase1.log retcode=`echo $?` case "$retcode" in 0) echo "SQL*Loader execution successful" ;; 1) echo "SQL*Loader execution exited with EX_FAIL, see logfile" ;; 2) echo "SQL*Loader execution exited with EX_WARN, see logfile" ;; 3) echo "SQL*Loader execution encountered a fatal error" ;; *) echo "unknown return code";; esac
|
Copyright © 1996, 2002 Oracle Corporation. All Rights Reserved. |
|