Large OLTP sites may suffer from Buffer Busy Waits. Hash Partitioning is one way to reduce it on both, Indexes and Tables. My last post demonstrated that for Indexes, now let’s see how it looks like with Tables. Initially there is a normal table that is not yet hash partitioned. If many sessions do insert now simultaneously, the problem shows:

Contention with a heap table
The last extent becomes a hot spot; all inserts go there and only a limited number of blocks is available. Therefore we will see Buffer Busy Waits. The playground:
SQL> create table t (id number, sometext varchar2(50)); Table created. create sequence id_seq; Sequence created. create or replace procedure manyinserts as begin for i in 1..10000 loop insert into t values (id_seq.nextval, 'DOES THIS CAUSE BUFFER BUSY WAITS?'); end loop; commit; end; / Procedure created. create or replace procedure manysessions as v_jobno number:=0; begin FOR i in 1..100 LOOP dbms_job.submit(v_jobno,'manyinserts;', sysdate); END LOOP; commit; end; / Procedure created.
The procedure manysessions is the way how I simulate OLTP end user activity on my demo system. Calling it leads to 100 job sessions. Each does 10.000 inserts:
SQL> exec manysessions PL/SQL procedure successfully completed. SQL> select count(*) from t; COUNT(*) ---------- 1000000 SQL> select object_name,subobject_name,value from v$segment_statistics where owner='ADAM' and statistic_name='buffer busy waits' and object_name = 'T'; OBJECT_NAM SUBOBJECT_ VALUE ---------- ---------- ---------- T 2985
So we got thousands of Buffer Busy Waits that way. Now the remedy:
SQL> drop table t purge; Table dropped. SQL> create table t (id number, sometext varchar2(50)) partition by hash (id) partitions 32; Table created. SQL> alter procedure manyinserts compile; Procedure altered. SQL> alter procedure manysessions compile; Procedure altered. SQL> exec manysessions PL/SQL procedure successfully completed. SQL> select count(*) from t; COUNT(*) ---------- 1000000 SQL> select object_name,subobject_name,value from v$segment_statistics where owner='ADAM' and statistic_name='buffer busy waits' and object_name = 'T'; OBJECT_NAM SUBOBJECT_ VALUE ---------- ---------- ---------- T SYS_P249 0 T SYS_P250 1 T SYS_P251 0 T SYS_P252 0 T SYS_P253 0 T SYS_P254 0 T SYS_P255 0 T SYS_P256 1 T SYS_P257 0 T SYS_P258 0 T SYS_P259 1 T SYS_P260 0 T SYS_P261 0 T SYS_P262 0 T SYS_P263 0 T SYS_P264 1 T SYS_P265 1 T SYS_P266 0 T SYS_P267 0 T SYS_P268 0 T SYS_P269 0 T SYS_P270 0 T SYS_P271 1 T SYS_P272 0 T SYS_P273 0 T SYS_P274 0 T SYS_P275 1 T SYS_P276 0 T SYS_P277 0 T SYS_P278 0 T SYS_P279 2 T SYS_P280 0 32 rows selected. SQL> select sum(value) from v$segment_statistics where owner='ADAM' and statistic_name='buffer busy waits' and object_name = 'T'; SUM(VALUE) ---------- 9 SQL> select 2985-9 as waits_gone from dual; WAITS_GONE ---------- 2976
The hot spot is gone:
This emphasizes again that Partitioning is not only for the Data Warehouse. Hash Partitioning in particular can be used to fight contention in OLTP environments.
#1 von adhikarexuss am Dezember 8, 2016 - 12:40
Hi Uwe,
Can that be done on an existing table which has grown to big?
Thank you,
Adhika