RE: How to do a bulk bind to load data into a table

2002-02-14 Thread Oberkofler, Dieter
Title: RE: How to do a bulk bind to load data into a table





from my understanding the FORALL statement only helps
you when processing data in collections or with BULK
when retrieving rows into collections. the bulk bind
functionality is btw only available starting with 9i.
you might want to try to bulk retrieve the data in
a collection and then to bulk insert it in the new table
but i would guess that the only real way to optimize your
statement might by to go for the insert into b select a
construct if this is an option in your case.


DO


-Original Message-
From: [EMAIL PROTECTED] [mailto:[EMAIL PROTECTED]]
Sent: Wednesday, February 13, 2002 22:05
To: Multiple recipients of list ORACLE-L
Subject: How to do a bulk bind to load data into a table



I'm looking at a way to speed up a huge insert (100K records at a time). In looking at FORALL, it looks like it could do what I want, but I'm not sure how to set it up correctly. What I currently do is:

set up a cursor, selecting the rows from table a
for cursor_rec in cursor_data loop
 insert into table b
 commit evey 2K rows
end loop


Is there a better way to do this?


Thank you for your help.



-- 
Please see the official ORACLE-L FAQ: http://www.orafaq.com
-- 
Author: 
 INET: [EMAIL PROTECTED]


Fat City Network Services -- (858) 538-5051 FAX: (858) 538-5051
San Diego, California -- Public Internet access / Mailing Lists

To REMOVE yourself from this mailing list, send an E-Mail message
to: [EMAIL PROTECTED] (note EXACT spelling of 'ListGuru') and in
the message BODY, include a line containing: UNSUB ORACLE-L
(or the name of mailing list you want to be removed from). You may
also send the HELP command for other information (like subscribing).





RE: How to do a bulk bind to load data into a table

2002-02-14 Thread Jamadagni, Rajendra

You can do it in 8i as well ...

CREATE OR REPLACE PACKAGE BODY Admin_Index AS
--
-- Define types
TYPE itt_OWNER IS TABLE OF NCS_INDEX_STATS.owner%TYPE
INDEX BY BINARY_INTEGER;
TYPE itt_NAME  IS TABLE OF NCS_INDEX_STATS.name%TYPE
INDEX BY BINARY_INTEGER;
TYPE itt_PARTITION_NAMEIS TABLE OF
NCS_INDEX_STATS.partition_name%TYPE INDEX BY BINARY_INTEGER;
TYPE itt_HEIGHTIS TABLE OF NCS_INDEX_STATS.height%TYPE
INDEX BY BINARY_INTEGER;
TYPE itt_BLOCKSIS TABLE OF NCS_INDEX_STATS.blocks%TYPE
INDEX BY BINARY_INTEGER;
TYPE itt_LF_ROWS   IS TABLE OF NCS_INDEX_STATS.lf_rows%TYPE
INDEX BY BINARY_INTEGER;
TYPE itt_LF_BLKS   IS TABLE OF NCS_INDEX_STATS.lf_blks%TYPE
INDEX BY BINARY_INTEGER;
TYPE itt_LF_ROWS_LEN   IS TABLE OF
NCS_INDEX_STATS.lf_rows_len%TYPE INDEX BY BINARY_INTEGER;
TYPE itt_LF_BLK_LENIS TABLE OF
NCS_INDEX_STATS.lf_blk_len%TYPE INDEX BY BINARY_INTEGER;
TYPE itt_BR_ROWS   IS TABLE OF NCS_INDEX_STATS.br_rows%TYPE
INDEX BY BINARY_INTEGER;
TYPE itt_BR_BLKS   IS TABLE OF NCS_INDEX_STATS.br_blks%TYPE
INDEX BY BINARY_INTEGER;
TYPE itt_BR_ROWS_LEN   IS TABLE OF
NCS_INDEX_STATS.br_rows_len%TYPE INDEX BY BINARY_INTEGER;
TYPE itt_BR_BLK_LENIS TABLE OF
NCS_INDEX_STATS.br_blk_len%TYPE INDEX BY BINARY_INTEGER;
TYPE itt_DEL_LF_ROWS   IS TABLE OF
NCS_INDEX_STATS.del_lf_rows%TYPE INDEX BY BINARY_INTEGER;
TYPE itt_DEL_LF_ROWS_LEN   IS TABLE OF
NCS_INDEX_STATS.del_lf_rows_len%TYPE INDEX BY BINARY_INTEGER;
TYPE itt_DISTINCT_KEYS IS TABLE OF
NCS_INDEX_STATS.distinct_keys%TYPE INDEX BY BINARY_INTEGER;
TYPE itt_MOST_REPEATED_KEY IS TABLE OF
NCS_INDEX_STATS.most_repeated_key%TYPE INDEX BY BINARY_INTEGER;
TYPE itt_BTREE_SPACE   IS TABLE OF
NCS_INDEX_STATS.btree_space%TYPE INDEX BY BINARY_INTEGER;
TYPE itt_USED_SPACEIS TABLE OF
NCS_INDEX_STATS.used_space%TYPE INDEX BY BINARY_INTEGER;
TYPE itt_PCT_USED  IS TABLE OF NCS_INDEX_STATS.pct_used%TYPE
INDEX BY BINARY_INTEGER;
TYPE itt_ROWS_PER_KEY  IS TABLE OF
NCS_INDEX_STATS.rows_per_key%TYPE INDEX BY BINARY_INTEGER;
TYPE itt_BLKS_GETS_PER_ACCESS  IS TABLE OF
NCS_INDEX_STATS.blks_gets_per_access%TYPE INDEX BY BINARY_INTEGER;
TYPE itt_PRE_ROWS  IS TABLE OF NCS_INDEX_STATS.pre_rows%TYPE
INDEX BY BINARY_INTEGER;
TYPE itt_PRE_ROWS_LEN  IS TABLE OF
NCS_INDEX_STATS.pre_rows_len%TYPE INDEX BY BINARY_INTEGER;
TYPE itt_TIMESTAMP IS TABLE OF
NCS_INDEX_STATS.timestamp%TYPE INDEX BY BINARY_INTEGER;
TYPE itt_COLL_DURA IS TABLE OF
NCS_INDEX_STATS.coll_dura%TYPE INDEX BY BINARY_INTEGER;
--
-- Define a record of Table ...
TYPE typeRecStats IS RECORD
  ( OWNER  itt_OWNER
   ,NAME   itt_NAME
   ,PARTITION_NAME itt_PARTITION_NAME
   ,HEIGHT itt_HEIGHT
   ,BLOCKS itt_BLOCKS
   ,LF_ROWSitt_LF_ROWS
   ,LF_BLKSitt_LF_BLKS
   ,LF_ROWS_LENitt_LF_ROWS_LEN
   ,LF_BLK_LEN itt_LF_BLK_LEN
   ,BR_ROWSitt_BR_ROWS
   ,BR_BLKSitt_BR_BLKS
   ,BR_ROWS_LENitt_BR_ROWS_LEN
   ,BR_BLK_LEN itt_BR_BLK_LEN
   ,DEL_LF_ROWSitt_DEL_LF_ROWS
   ,DEL_LF_ROWS_LENitt_DEL_LF_ROWS_LEN
   ,DISTINCT_KEYS  itt_DISTINCT_KEYS
   ,MOST_REPEATED_KEY  itt_MOST_REPEATED_KEY
   ,BTREE_SPACEitt_BTREE_SPACE
   ,USED_SPACE itt_USED_SPACE
   ,PCT_USED   itt_PCT_USED
   ,ROWS_PER_KEY   itt_ROWS_PER_KEY
   ,BLKS_GETS_PER_ACCESS   itt_BLKS_GETS_PER_ACCESS
   ,PRE_ROWS   itt_PRE_ROWS
   ,PRE_ROWS_LEN   itt_PRE_ROWS_LEN
   ,TIMESTAMP  itt_TIMESTAMP
   ,COLL_DURA  itt_COLL_DURA);
--
-- Global table
recStats   typeRecStats;
..
PROCEDURE MOVE_STATS_TO_TABLE IS
--
BEGIN
FORALL i IN recStats.OWNER.first .. recStats.OWNER.last
INSERT INTO NCS_INDEX_STATS
( OWNER ,NAME
,PARTITION_NAME ,HEIGHT
,BLOCKS ,LF_ROWS
,LF_BLKS ,LF_ROWS_LEN
,LF_BLK_LEN ,BR_ROWS
,BR_BLKS ,BR_ROWS_LEN
,BR_BLK_LEN ,DEL_LF_ROWS
,DEL_LF_ROWS_LEN ,DISTINCT_KEYS
,MOST_REPEATED_KEY ,BTREE_SPACE
,USED_SPACE ,PCT_USED
,ROWS_PER_KEY ,BLKS_GETS_PER_ACCESS
,PRE_ROWS ,PRE_ROWS_LEN
,TIMESTAMP ,COLL_DURA )
VALUES
( recStats.OWNER(i) ,recStats.NAME(i)
,recStats.PARTITION_NAME(i) ,recStats.HEIGHT(i)
,recStats.BLOCKS(i) ,recStats.LF_ROWS(i)
,recStats.LF_BLKS(i) ,recStats.LF_ROWS_LEN(i)
,recStats.LF_BLK_LEN(i) ,recStats.BR_ROWS(i)
,recStats.BR_BLKS(i) ,recStats.BR_ROWS_LEN(i)
,recStats.BR_BLK_LEN(i)