Insert performance
David Pujol, November 13, 2004 - 12:05 pm UTC
Sorry for delay, I've been shutdown ...
My script ......
CREATE TABLE TMP_CDHHAB_M
(
IDTMPCDHOTELES NUMBER NOT NULL,
IDTIPHAB VARCHAR2(4) NOT NULL,
ADUREGIMENPEDI VARCHAR2(2) DEFAULT ' ' NOT NULL,
NINREGIMENPEDI VARCHAR2(2) DEFAULT ' ' NOT NULL,
CANTIDADPEDIDAS NUMBER DEFAULT 0 NOT NULL,
CANTIDADSELECC NUMBER DEFAULT 0 NOT NULL,
ESTADO VARCHAR2(1) DEFAULT 'O' NOT NULL,
ADULTOS NUMBER DEFAULT 0 NOT NULL,
ADUREGIMENINCL VARCHAR2(2) DEFAULT ' ' NOT NULL,
ADUREGDIAS VARCHAR2(1) DEFAULT 'T' NOT NULL,
NINOS NUMBER DEFAULT 0 NOT NULL,
NINREGIMENINCL VARCHAR2(2) DEFAULT ' ' NOT NULL,
NINREGDIAS VARCHAR2(1) DEFAULT 'T' NOT NULL,
PRECIOVENTA NUMBER(11,2) DEFAULT 0 NOT NULL,
PRECIOCOSTE NUMBER(11,2) DEFAULT 0 NOT NULL,
NOTASHAB VARCHAR2(2000),
EDADNINO1 NUMBER(2),
EDADNINO2 NUMBER(2),
FORZARPETICIONSN VARCHAR2(1) DEFAULT 'N'
)
PCTUSED 60
PCTFREE 40
INITRANS 5
MAXTRANS 255
STORAGE (
INITIAL 1M
NEXT 1M
PCTINCREASE 0
FREELISTS 64
FREELIST GROUPS 4
)
NOLOGGING
-- PARTITION BY HASH (IDTMPCDHOTELES) partitions 64
NOCACHE
NOPARALLEL
ENABLE ROW MOVEMENT
/
CREATE UNIQUE INDEX TMP_CDHHAB_M_ID_PK ON TMP_CDHHAB_M
(IDTMPCDHOTELES, IDTIPHAB, ADUREGIMENPEDI, NINREGIMENPEDI)
PCTFREE 40
INITRANS 5
MAXTRANS 255
STORAGE (
INITIAL 1M
NEXT 1M
FREELISTS 64
FREELIST GROUPS 4
)
NOLOGGING
-- LOCAL
NOPARALLEL
/
ALTER TABLE TMP_CDHHAB_M ADD (
CONSTRAINT TMP_CDHHAB_M_ID_PK PRIMARY KEY (IDTMPCDHOTELES, IDTIPHAB, ADUREGIMENPEDI, NINREGIMENPEDI) USING INDEX LOCAL);
CREATE TABLE TMP_CDHHDESG_M
(
IDTMPCDHOTELES NUMBER NOT NULL,
IDTIPHAB VARCHAR2(4) NOT NULL,
ADUREGIMENPEDI VARCHAR2(2) DEFAULT ' ' NOT NULL,
NINREGIMENPEDI VARCHAR2(2) DEFAULT ' ' NOT NULL,
FECHA DATE NOT NULL,
ESTADO VARCHAR2(1) DEFAULT 'X' NOT NULL,
NOTAS VARCHAR2(200),
NUMHABDISP NUMBER DEFAULT 0 NOT NULL,
NUMHABPETI NUMBER DEFAULT 0 NOT NULL,
CUPOOVENTA VARCHAR2(1) DEFAULT 'V' NOT NULL,
TIPHABCOG VARCHAR2(4),
IDTIPTAR VARCHAR2(2),
IDTIPTEM VARCHAR2(2),
IDPRODUCTOS NUMBER,
CLIPRECIOHAB NUMBER(11,2) DEFAULT 0 NOT NULL,
CLIPRECIOREG NUMBER(11,2) DEFAULT 0 NOT NULL,
HOTPRECIOHAB NUMBER(11,2) DEFAULT 0 NOT NULL,
HOTPRECIOREG NUMBER(11,2) DEFAULT 0 NOT NULL,
ADUREGIMENINCL VARCHAR2(2),
NINREGIMENINCL VARCHAR2(2),
SUPLESTINF NUMBER(3),
TIPONIN1 VARCHAR2(1),
DESOSUPNIN1 VARCHAR2(1),
PORCENIN1 NUMBER(5,2),
IMPNIN1 NUMBER(8,2),
SOBRENIN1 VARCHAR2(1),
TIPONIN2 VARCHAR2(1),
DESOSUPNIN2 VARCHAR2(1),
PORCENIN2 NUMBER(5,2),
IMPNIN2 NUMBER(8,2),
SOBRENIN2 VARCHAR2(1),
NETAOCOMIS VARCHAR2(1),
COMISIONA VARCHAR2(1),
PORCIVA NUMBER(4,2),
TIPO3APERS VARCHAR2(1),
DESOSUP3APERS VARCHAR2(1),
PORCEN3APERS NUMBER(5,2),
IMP3APERS NUMBER(8,2),
SOBRE3APERS VARCHAR2(1),
TIPO4APERS VARCHAR2(1),
DESOSUP4APERS VARCHAR2(1),
PORCEN4APERS NUMBER(5,2),
IMP4APERS NUMBER(8,2),
SOBRE4APERS VARCHAR2(1),
DTOVAN NUMBER(5,2),
IDPRODUCTOS_TAR NUMBER,
IDHOTELESCUPO NUMBER,
FORZARPETICIONSN VARCHAR2(1) DEFAULT 'N'
)
PCTUSED 60
PCTFREE 40
INITRANS 5
MAXTRANS 255
STORAGE (
INITIAL 1M
NEXT 1M
MINEXTENTS 1
MAXEXTENTS 2147483645
PCTINCREASE 0
FREELISTS 64
FREELIST GROUPS 4
)
NOLOGGING
-- PARTITION BY HASH (IDTMPCDHOTELES, IDTIPHAB) PARTITIONS 8
NOCACHE
NOPARALLEL
ENABLE ROW MOVEMENT
/
CREATE UNIQUE INDEX TMP_CDHHDESG_M_ID_PK ON TMP_CDHHDESG_M
(IDTMPCDHOTELES, IDTIPHAB, ADUREGIMENPEDI, NINREGIMENPEDI, FECHA)
PCTFREE 40
INITRANS 5
MAXTRANS 255
STORAGE (
INITIAL 1M
NEXT 1M
FREELISTS 64
FREELIST GROUPS 4
)
NOLOGGING
-- LOCAL
NOPARALLEL
/
CREATE INDEX TMPCDHHDESGM_CUPO_I ON TMP_CDHHDESG_M
(IDHOTELESCUPO)
PCTFREE 40
INITRANS 5
MAXTRANS 255
STORAGE (
INITIAL 1M
NEXT 1M
MINEXTENTS 1
MAXEXTENTS 2147483645
PCTINCREASE 0
FREELISTS 64
FREELIST GROUPS 4
)
NOLOGGING
-- LOCAL
NOPARALLEL
/
ALTER TABLE TMP_CDHHDESG_M ADD (
CONSTRAINT TMP_CDHHDESG_M_ID_PK PRIMARY KEY (IDTMPCDHOTELES, IDTIPHAB, ADUREGIMENPEDI, NINREGIMENPEDI, FECHA) );
My testcase .....
exec dbms_stats.set_table_stats ('testcase', 'tmp_cdhhab_m', numrows=>1000000, numblks=>20000);
exec dbms_stats.set_table_stats ('testcase', 'tmp_cdhhdesg_m', numrows=>5000000, numblks=>50000);
begin
for i in 1 .. 100
loop
INSERTING_TESTCASE;
end loop;
end;
/
procedure INSERTING_TESTCASE is:
insert into TMP_CDHHAB_M
insert into TMP_CDHHDESG_M
I've created this testcase:
1- PARTITIONS 64
PCTFREE 20
FREELISTS 24
ALL INDEXES ARE LOCAL
all CONSTRAINTS
********************************************************************************
INSERT INTO TMP_CDHHAB_M ( IDTMPCDHOTELES ,IDTIPHAB ,ADUREGIMENPEDI ,
NINREGIMENPEDI ,CANTIDADPEDIDAS ,CANTIDADSELECC ,ESTADO ,ADULTOS ,
ADUREGIMENINCL ,ADUREGDIAS ,NINOS ,NINREGIMENINCL ,NINREGDIAS ,PRECIOVENTA ,
PRECIOCOSTE ,NOTASHAB )
VALUES
(:B3 ,'1' ,:B2 ,:B1 ,2 ,4 ,'A' ,2 ,'MD' ,'S' ,4 ,'AD' ,'A' ,450 ,578 ,'Notas
varias de la habitación, se trata de un varchar2(4000) que igual para la
demo debería pasarse a un char de 200')
call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 1 0.00 0.00 0 0 0 0
Execute 100 0.02 2.70 58 105 643 100
Fetch 0 0.00 0.00 0 0 0 0
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 101 0.02 2.70 58 105 643 100
Misses in library cache during parse: 0
Optimizer goal: CHOOSE
Parsing user id: 48 (recursive depth: 1)
Elapsed times include waiting on following events:
Event waited on Times Max. Wait Total Waited
---------------------------------------- Waited ---------- ------------
db file sequential read 58 0.56 2.68
********************************************************************************
INSERT INTO TMP_CDHHDESG_M (IDTMPCDHOTELES ,IDTIPHAB ,ADUREGIMENPEDI ,
NINREGIMENPEDI ,FECHA ,ESTADO ,NOTAS ,NUMHABDISP ,NUMHABPETI ,CUPOOVENTA ,
CLIPRECIOHAB ,CLIPRECIOREG ,HOTPRECIOHAB ,HOTPRECIOREG ,IDHOTELESCUPO)
VALUES
(:B1 ,'1' ,:B4 ,:B3 ,(SYSDATE+ (:B2/86400)) ,'A' ,'notas varias.
Insertaremos unas pocas .................' ,2 ,3 ,'A' ,1000 ,1000 ,1999 ,
2121 ,:B1)
call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 1 0.00 0.00 0 0 0 0
Execute 99900 13.03 41.56 1223 104221 834466 99900
Fetch 0 0.00 0.00 0 0 0 0
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 99901 13.03 41.56 1223 104221 834466 99900
Misses in library cache during parse: 0
Optimizer goal: CHOOSE
Parsing user id: 48 (recursive depth: 1)
Elapsed times include waiting on following events:
Event waited on Times Max. Wait Total Waited
---------------------------------------- Waited ---------- ------------
db file sequential read 1229 1.39 20.58
log file sync 6 0.00 0.00
control file sequential read 36 0.09 0.36
async disk IO 15 0.00 0.00
db file single write 3 0.00 0.00
control file parallel write 6 0.00 0.00
rdbms ipc reply 3 0.25 0.71
log buffer space 7 1.02 4.14
log file switch completion 1 0.18 0.18
********************************************************************************
2- PARTITIONS 32
PCTFREE 20
FREELISTS 24
ALL INDEXES ARE LOCAL
WITHOUT CONSTRAINTS
********************************************************************************
INSERT INTO TMP_CDHHAB_M ( IDTMPCDHOTELES ,IDTIPHAB ,ADUREGIMENPEDI ,
NINREGIMENPEDI ,CANTIDADPEDIDAS ,CANTIDADSELECC ,ESTADO ,ADULTOS ,
ADUREGIMENINCL ,ADUREGDIAS ,NINOS ,NINREGIMENINCL ,NINREGDIAS ,PRECIOVENTA ,
PRECIOCOSTE ,NOTASHAB )
VALUES
(:B3 ,'1' ,:B2 ,:B1 ,2 ,4 ,'A' ,2 ,'MD' ,'S' ,4 ,'AD' ,'A' ,450 ,578 ,'Notas
varias de la habitación, se trata de un varchar2(4000) que igual para la
demo debería pasarse a un char de 200')
call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 1 0.00 0.00 0 0 0 0
Execute 100 0.07 2.62 40 103 609 100
Fetch 0 0.00 0.00 0 0 0 0
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 101 0.07 2.62 40 103 609 100
Misses in library cache during parse: 1
Optimizer goal: CHOOSE
Parsing user id: 48 (recursive depth: 1)
Elapsed times include waiting on following events:
Event waited on Times Max. Wait Total Waited
---------------------------------------- Waited ---------- ------------
db file sequential read 40 0.88 2.55
********************************************************************************
INSERT INTO TMP_CDHHDESG_M (IDTMPCDHOTELES ,IDTIPHAB ,ADUREGIMENPEDI ,
NINREGIMENPEDI ,FECHA ,ESTADO ,NOTAS ,NUMHABDISP ,NUMHABPETI ,CUPOOVENTA ,
CLIPRECIOHAB ,CLIPRECIOREG ,HOTPRECIOHAB ,HOTPRECIOREG ,IDHOTELESCUPO)
VALUES
(:B1 ,'1' ,:B4 ,:B3 ,(SYSDATE+ (:B2/86400)) ,'A' ,'notas varias.
Insertaremos unas pocas .................' ,2 ,3 ,'A' ,1000 ,1000 ,1999 ,
2121 ,:B1)
call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 1 0.00 0.00 0 0 0 0
Execute 99900 11.91 37.75 888 103955 731274 99900
Fetch 0 0.00 0.00 0 0 0 0
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 99901 11.91 37.75 888 103955 731274 99900
Misses in library cache during parse: 1
Optimizer goal: CHOOSE
Parsing user id: 48 (recursive depth: 1)
Elapsed times include waiting on following events:
Event waited on Times Max. Wait Total Waited
---------------------------------------- Waited ---------- ------------
db file sequential read 892 2.31 18.20
control file sequential read 36 0.02 0.19
async disk IO 15 0.00 0.00
db file single write 3 0.00 0.00
control file parallel write 6 0.00 0.00
rdbms ipc reply 3 0.18 0.55
log buffer space 10 0.66 1.55
log file sync 6 0.00 0.01
log file switch completion 2 0.20 0.36
********************************************************************************
3- PARTITIONS 16
PCTFREE 30
FREELISTS 24
ALL INDEXES ARE LOCAL
without CONSTRAINTS
********************************************************************************
INSERT INTO TMP_CDHHAB_M ( IDTMPCDHOTELES ,IDTIPHAB ,ADUREGIMENPEDI ,
NINREGIMENPEDI ,CANTIDADPEDIDAS ,CANTIDADSELECC ,ESTADO ,ADULTOS ,
ADUREGIMENINCL ,ADUREGDIAS ,NINOS ,NINREGIMENINCL ,NINREGDIAS ,PRECIOVENTA ,
PRECIOCOSTE ,NOTASHAB )
VALUES
(:B3 ,'1' ,:B2 ,:B1 ,2 ,4 ,'A' ,2 ,'MD' ,'S' ,4 ,'AD' ,'A' ,450 ,578 ,'Notas
varias de la habitación, se trata de un varchar2(4000) que igual para la
demo debería pasarse a un char de 200')
call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 1 0.00 0.00 0 0 0 0
Execute 100 0.04 1.30 18 103 608 100
Fetch 0 0.00 0.00 0 0 0 0
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 101 0.04 1.30 18 103 608 100
Misses in library cache during parse: 1
Optimizer goal: CHOOSE
Parsing user id: 48 (recursive depth: 1)
Elapsed times include waiting on following events:
Event waited on Times Max. Wait Total Waited
---------------------------------------- Waited ---------- ------------
db file sequential read 18 0.64 1.20
********************************************************************************
INSERT INTO TMP_CDHHDESG_M (IDTMPCDHOTELES ,IDTIPHAB ,ADUREGIMENPEDI ,
NINREGIMENPEDI ,FECHA ,ESTADO ,NOTAS ,NUMHABDISP ,NUMHABPETI ,CUPOOVENTA ,
CLIPRECIOHAB ,CLIPRECIOREG ,HOTPRECIOHAB ,HOTPRECIOREG ,IDHOTELESCUPO)
VALUES
(:B1 ,'1' ,:B4 ,:B3 ,(SYSDATE+ (:B2/86400)) ,'A' ,'notas varias.
Insertaremos unas pocas .................' ,2 ,3 ,'A' ,1000 ,1000 ,1999 ,
2121 ,:B1)
call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 1 0.00 0.00 0 0 0 0
Execute 99900 9.39 32.79 318 104288 731466 99900
Fetch 0 0.00 0.00 0 0 0 0
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 99901 9.39 32.79 318 104288 731466 99900
Misses in library cache during parse: 1
Optimizer goal: CHOOSE
Parsing user id: 48 (recursive depth: 1)
Elapsed times include waiting on following events:
Event waited on Times Max. Wait Total Waited
---------------------------------------- Waited ---------- ------------
db file sequential read 325 1.34 9.21
log buffer space 31 1.02 5.73
control file sequential read 48 0.04 0.35
async disk IO 20 0.00 0.00
db file single write 4 0.00 0.00
control file parallel write 8 0.00 0.01
rdbms ipc reply 4 0.28 0.95
log file sync 6 1.02 1.64
log file switch completion 2 0.19 0.35
********************************************************************************
4- PARTITIONS 8
PCTFREE 20
FREELISTS 24
ALL INDEXES ARE LOCAL
without CONSTRAINTS
********************************************************************************
INSERT INTO TMP_CDHHAB_M ( IDTMPCDHOTELES ,IDTIPHAB ,ADUREGIMENPEDI ,
NINREGIMENPEDI ,CANTIDADPEDIDAS ,CANTIDADSELECC ,ESTADO ,ADULTOS ,
ADUREGIMENINCL ,ADUREGDIAS ,NINOS ,NINREGIMENINCL ,NINREGDIAS ,PRECIOVENTA ,
PRECIOCOSTE ,NOTASHAB )
VALUES
(:B3 ,'1' ,:B2 ,:B1 ,2 ,4 ,'A' ,2 ,'MD' ,'S' ,4 ,'AD' ,'A' ,450 ,578 ,'Notas
varias de la habitación, se trata de un varchar2(4000) que igual para la
demo debería pasarse a un char de 200')
call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 1 0.00 0.00 0 0 0 0
Execute 100 0.01 0.12 2 109 637 100
Fetch 0 0.00 0.00 0 0 0 0
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 101 0.01 0.12 2 109 637 100
Misses in library cache during parse: 1
Optimizer goal: CHOOSE
Parsing user id: 48 (recursive depth: 1)
Elapsed times include waiting on following events:
Event waited on Times Max. Wait Total Waited
---------------------------------------- Waited ---------- ------------
db file sequential read 2 0.05 0.09
********************************************************************************
INSERT INTO TMP_CDHHDESG_M (IDTMPCDHOTELES ,IDTIPHAB ,ADUREGIMENPEDI ,
NINREGIMENPEDI ,FECHA ,ESTADO ,NOTAS ,NUMHABDISP ,NUMHABPETI ,CUPOOVENTA ,
CLIPRECIOHAB ,CLIPRECIOREG ,HOTPRECIOHAB ,HOTPRECIOREG ,IDHOTELESCUPO)
VALUES
(:B1 ,'1' ,:B4 ,:B3 ,(SYSDATE+ (:B2/86400)) ,'A' ,'notas varias.
Insertaremos unas pocas .................' ,2 ,3 ,'A' ,1000 ,1000 ,1999 ,
2121 ,:B1)
call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 1 0.01 0.00 0 0 0 0
Execute 99900 10.32 29.87 257 104174 731180 99900
Fetch 0 0.00 0.00 0 0 0 0
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 99901 10.33 29.87 257 104174 731180 99900
Misses in library cache during parse: 1
Optimizer goal: CHOOSE
Parsing user id: 48 (recursive depth: 1)
Elapsed times include waiting on following events:
Event waited on Times Max. Wait Total Waited
---------------------------------------- Waited ---------- ------------
db file sequential read 264 0.80 7.80
log file sync 11 0.00 0.01
control file sequential read 48 0.10 0.42
async disk IO 20 0.00 0.00
db file single write 4 0.00 0.00
control file parallel write 8 0.00 0.01
rdbms ipc reply 4 0.27 0.87
log buffer space 22 1.02 2.30
free buffer waits 3 1.02 2.25
log file switch completion 2 0.18 0.33
********************************************************************************
4- NO PARTITIONS
PCTFREE 40
FREELISTS 64
FREELIST GROUPS 4
without CONSTRAINTS
********************************************************************************
INSERT INTO TMP_CDHHAB_M ( IDTMPCDHOTELES ,IDTIPHAB ,ADUREGIMENPEDI ,
NINREGIMENPEDI ,CANTIDADPEDIDAS ,CANTIDADSELECC ,ESTADO ,ADULTOS ,
ADUREGIMENINCL ,ADUREGDIAS ,NINOS ,NINREGIMENINCL ,NINREGDIAS ,PRECIOVENTA ,
PRECIOCOSTE ,NOTASHAB )
VALUES
(:B3 ,'1' ,:B2 ,:B1 ,2 ,4 ,'A' ,2 ,'MD' ,'S' ,4 ,'AD' ,'A' ,450 ,578 ,'Notas
varias de la habitación, se trata de un varchar2(4000) que igual para la
demo debería pasarse a un char de 200')
call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 1 0.00 0.00 0 0 0 0
Execute 100 0.04 0.28 6 10 459 100
Fetch 0 0.00 0.00 0 0 0 0
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 101 0.04 0.28 6 10 459 100
Misses in library cache during parse: 1
Optimizer goal: CHOOSE
Parsing user id: 48 (recursive depth: 1)
Elapsed times include waiting on following events:
Event waited on Times Max. Wait Total Waited
---------------------------------------- Waited ---------- ------------
db file sequential read 6 0.14 0.24
********************************************************************************
INSERT INTO TMP_CDHHDESG_M (IDTMPCDHOTELES ,IDTIPHAB ,ADUREGIMENPEDI ,
NINREGIMENPEDI ,FECHA ,ESTADO ,NOTAS ,NUMHABDISP ,NUMHABPETI ,CUPOOVENTA ,
CLIPRECIOHAB ,CLIPRECIOREG ,HOTPRECIOHAB ,HOTPRECIOREG ,IDHOTELESCUPO)
VALUES
(:B1 ,'1' ,:B4 ,:B3 ,(SYSDATE+ (:B2/86400)) ,'A' ,'notas varias.
Insertaremos unas pocas .................' ,2 ,3 ,'A' ,1000 ,1000 ,1999 ,
2121 ,:B1)
call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 1 0.00 0.00 0 0 0 0
Execute 99900 8.59 21.68 1 4157 732542 99900
Fetch 0 0.00 0.00 0 0 0 0
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 99901 8.59 21.68 1 4157 732542 99900
Misses in library cache during parse: 1
Optimizer goal: CHOOSE
Parsing user id: 48 (recursive depth: 1)
Elapsed times include waiting on following events:
Event waited on Times Max. Wait Total Waited
---------------------------------------- Waited ---------- ------------
log buffer space 43 1.02 4.89
log file sync 4 0.08 0.09
control file sequential read 36 0.17 0.97
db file sequential read 6 0.03 0.10
async disk IO 15 0.00 0.00
db file single write 3 0.03 0.03
control file parallel write 6 0.02 0.03
rdbms ipc reply 3 0.43 0.91
log file switch completion 1 0.16 0.16
********************************************************************************
My conclusion is:
- With 64 partitions I had 64x24 insert points, but I think that there was a lot of cost of insert.
- With 32 partitions I had 32x24 insert points, insert had less cost ..
- .....
- I think that the problem with blocks (doubled in 64 partitions) was caused by delayed block cleanout. Remember that I had one job who deletes every 5 minutes historical data. Now, without partitions, I've improve insert performance (testcase) and I've removed the deletes job. These tables have not constraints now. I've added 4 freelists groups to minimize a possible bottleneck in freelists (these tables will be truncated every week) and it seems that run very well. The last statspack is the best (without partitioning).
I've spread more the rows (pctfree 40) and it seems that now there are less buffer busy waits too.
This is my testcase,
a lot of thanks Tom.
Atentament
David Pujol
November 13, 2004 - 1:20 pm UTC
i'm confused here -- your original question was
..
now, i'm getting poor performance than when I had 32 partitions only:
.....
or to paraphrase: why is 64 partitions so much slower
but your numbers have shown that 64/32 -- no big difference? We were not comparing partitioned vs non-partitioned. And remember -- your initial discussion included:
...
To avoid block contention we was hash-partitioned this tables.
......
so, you were having multi-user concurrency issues, a single user test cannot be used to show your better off now.