Oracle9i Database Concepts
Release 1 (9.0.1)

Part Number A88856-02
Go To Documentation Library
Home
Go To Product List
Book List
Go To Table Of Contents
Contents
Go To Index
Index

Master Index

Feedback

Go to previous page Go to next page

21
Direct-Path INSERT

This chapter describes the Oracle direct-path INSERT feature for serial or parallel inserts. It also describes the NOLOGGING feature that is available for direct-path INSERT and some DDL statements. This chapter's topics include:

Introduction to Direct-Path INSERT

Oracle inserts data into a table in one of two ways:

You can implement direct-path insert operations by using direct-path INSERT statements or by using Oracle's direct-path loader utility, SQL*Loader. This section discusses direct-path INSERT. For information on direct-path load, please refer to the documentation on SQL*Loader in Oracle9i Database Utilities.


Note:

Direct-path INSERT is subject to a number of restrictions. For a listing of these restriction, please refer to Oracle9i SQL Reference. 


Advantages of Direct-Path INSERT

The performance benefits of direct-path INSERT arise from several factors:

Serial and Parallel Direct-Path INSERT

When you are inserting in parallel DML mode, direct-path INSERT is the default. In order to be running in parallel DML mode, the following requirements must be met:

You can disable direct-path INSERT by specifying the NOAPPEND hint in each INSERT statement. Doing so overrides parallel DML mode.

See Also:

Oracle9i Database Performance Guide and Reference for more information on using hints 

When you are inserting in serial mode, you must activate direct-path INSERT by specifying the APPEND hint in each insert statement, either immediately after the INSERT keyword, or immediately after the SELECT keyword in the subquery of the INSERT statement.


Note:

Direct-path INSERT supports only the subquery syntax of the INSERT statement, not the VALUES clause. For more information on the subquery syntax of INSERT statements, refer to Oracle9i SQL Reference. 


Direct-Path INSERT Into Partitioned and Nonpartitioned Tables

You can use direct-path INSERT on both partitioned and nonpartitioned tables.

Serial Direct-Path Insert into Partitioned and Nonpartitioned Tables

The single process inserts data beyond the current high water mark of the table segment or of each partition segment. (The high-water mark is the level at which blocks have never been formatted to receive data.) When a COMMIT executes, the high-water mark is updated to the new value, making the data visible to users.

Parallel Direct-Path INSERT into Partitioned Tables

This situation is analogous to serial direct-path INSERT. Each parallel execution server is assigned one or more partitions, with no more than one process working on a single partition. Each parallel execution server inserts data beyond the current high-water mark of its assigned partition segment(s). When a COMMIT executes, the high-water mark of each partition segment is updated to its new value, making the data visible to users.

Parallel Direct-Path INSERT into a Nonpartitioned Table

Each parallel execution server allocates a new temporary segment and inserts data into that temporary segment. When a COMMIT executes, the parallel execution coordinator merges the new temporary segments into the primary table segment, where it is visible to users.

Direct-Path INSERT and Logging Mode

Direct-path INSERT lets you choose whether to log redo and undo information during the insert operation.

Direct-Path INSERT with Logging

In this mode, Oracle performs full redo logging for instance and media recovery. If the database is in ARCHIVELOG mode, you can archive online redo logs to tape. If the database is in NOARCHIVELOG mode, you can recover instance crashes but not disk failures.

Direct-Path INSERT without Logging

In this mode, Oracle inserts data without redo or undo logging. (Some minimal logging is done to mark new extents invalid, and data dictionary changes are always logged.) This mode improves performance. However, if you subsequently must perform media recovery, the extent invalidation records mark a range of blocks as logically corrupt, because no redo data was logged for them. Therefore, it is important that you back up the data after such an insert operation.

See Also:

 

Additional Considerations for Direct-Path INSERT

Index Maintenance

Oracle performs index maintenance at the end of direct-path INSERT operations on tables (partitioned or nonpartitioned) that have indexes. This index maintenance is performed by the parallel execution servers for parallel direct-path INSERT or by the single process for serial direct-path INSERT. You can avoid the performance impact of index maintenance by dropping the index before the INSERT operation and then rebuilding it afterward.

Space Considerations

Direct-path INSERT requires more space than conventional-path INSERT, because direct-path INSERT does not use existing space in the free lists of the segment.

All serial direct-path INSERT operations as well as parallel direct-path INSERT into partitioned tables insert data above the high-water mark of the affected segment. This requires some additional space.

Parallel direct-path INSERT into nonpartitioned tables requires even more space, because it creates a temporary segment for each degree of parallelism. If the nonpartitioned table is not in a locally managed tablespace in automatic mode, you can modify the values of the NEXT and PCTINCREASE storage parameter and MINIMUM EXTENT tablespace parameter to provide sufficient (but not excess) storage for the temporary segments. Choose values for these parameters so that:

After the direct-path INSERT operation is complete, you can reset these parameters to settings more appropriate for serial operations.

Locking Considerations

During direct-path INSERT, Oracle obtains exclusive locks on the table (or on all partitions of a partitioned table). As a result, users cannot perform any concurrent insert, update, or delete operations on the table, and concurrent index creation and build operations are not permitted. Concurrent queries, however, are supported, but the query will return only the information before the insert operation.


Go to previous page Go to next page
Oracle
Copyright © 1996-2001, Oracle Corporation.

All Rights Reserved.
Go To Documentation Library
Home
Go To Product List
Book List
Go To Table Of Contents
Contents
Go To Index
Index

Master Index

Feedback