Beiträge getaggt mit Performance Tuning

Partition-Pruning: Do & Don’t

do-dont

This is about how to write SQL in a way that supports Partition-Pruning – and what should be avoided.  The playing field looks as follows:

SQL> select * from v$version;
BANNER
 --------------------------------------------------------------------------------
 Oracle Database 11g Enterprise Edition Release 11.2.0.2.0 - Production
 PL/SQL Release 11.2.0.2.0 - Production
 CORE    11.2.0.2.0      Production
 TNS for Linux: Version 11.2.0.2.0 - Production
 NLSRTL Version 11.2.0.2.0 - Production

SQL> select table_name,partitioning_type,partition_count from user_part_tables where table_name='SALES_YEAR';
TABLE_NAME                     PARTITION PARTITION_COUNT
 ------------------------------ --------- ---------------
 SALES_YEAR                     RANGE             1048575

SQL> select segment_name,partition_name,sum(bytes)/1024/1024 as mb
 from user_segments where segment_name='SALES_YEAR'
 group by rollup (segment_name,partition_name)
 order by 1,2; 

SEGMENT_NAME                   PARTITION_NAME                         MB
 ------------------------------ ------------------------------ ----------
 SALES_YEAR                     P1                                     16
 SALES_YEAR                     SYS_P181                               32
 SALES_YEAR                     SYS_P182                               32
 SALES_YEAR                     SYS_P183                               32
 SALES_YEAR                     SYS_P184                               32
 SALES_YEAR                     SYS_P185                               32
 SALES_YEAR                     SYS_P186                               32
 SALES_YEAR                     SYS_P187                               32
 SALES_YEAR                     SYS_P188                               32
 SALES_YEAR                     SYS_P189                               32
 SALES_YEAR                     SYS_P190                               32
 SALES_YEAR                     SYS_P191                               32
 SALES_YEAR                     SYS_P192                               32
 SALES_YEAR                     SYS_P193                               32
 SALES_YEAR                     SYS_P194                               32
 SALES_YEAR                     SYS_P195                               32
 SALES_YEAR                     SYS_P196                               32
 SALES_YEAR                     SYS_P197                               32
 SALES_YEAR                     SYS_P198                               32
 SALES_YEAR                     SYS_P199                               32
 SALES_YEAR                     SYS_P200                               32
 SALES_YEAR                     SYS_P201                               32
 SALES_YEAR                     SYS_P202                               32
 SALES_YEAR                     SYS_P203                               32
 SALES_YEAR                     SYS_P204                               32
 SALES_YEAR                     SYS_P205                               32
 SALES_YEAR                     SYS_P206                               32
 SALES_YEAR                     SYS_P207                               24
 SALES_YEAR                                                           872
 872
30 rows selected.

SQL> select to_char(order_date,'yyyy'),count(*) from sales_year group by to_char(order_date,'yyyy') order by 1;


TO_C   COUNT(*)
 ---- ----------
 1985     158000
 1986     365000
 1987     365000
 1988     366000
 1989     365000
 1990     365000
 1991     365000
 1992     366000
 1993     365000
 1994     365000
 1995     365000
 1996     366000
 1997     365000
 1998     365000
 1999     365000
 2000     366000
 2001     365000
 2002     365000
 2003     365000
 2004     366000
 2005     365000
 2006     365000
 2007     365000
 2008     366000
 2009     365000
 2010     365000
 2011     365000
 2012     346000
28 rows selected.

My moderately sized table is Interval partitioned (therefore PARTITION_COUNT in USER_PART_TABLES shows the possible  maximum number)  by the year on ORDER_DATE with 28 partitions. Now imagine we want to have the summarized AMOUNT_SOLD of the year 2011. What about this statement?

SQL> set timing on
SQL> select sum(amount_sold) from sales_year where to_char(order_date,'yyyy')='2011';

SUM(AMOUNT_SOLD)
----------------
      1825000000

Elapsed: 00:00:05.15
SQL> select plan_table_output from table(dbms_xplan.display_cursor);

PLAN_TABLE_OUTPUT
---------------------------------------------------------------------------------------------------
SQL_ID  cv54q4mt7ajjr, child number 0
-------------------------------------
select sum(amount_sold) from sales_year where
to_char(order_date,'yyyy')='2011'

Plan hash value: 3345868052

---------------------------------------------------------------------------------------------------
| Id  | Operation            | Name       | Rows  | Bytes | Cost (%CPU)| Time     | Pstart| Pstop |
---------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT     |            |       |       | 24384 (100)|          |       |       |
|   1 |  SORT AGGREGATE      |            |     1 |    22 |            |          |       |       |
|   2 |   PARTITION RANGE ALL|            |   287K|  6181K| 24384   (2)| 00:00:07 |     1 |1048575|
|*  3 |    TABLE ACCESS FULL | SALES_YEAR |   287K|  6181K| 24384   (2)| 00:00:07 |     1 |1048575|
---------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   3 - filter(TO_CHAR(INTERNAL_FUNCTION("ORDER_DATE"),'yyyy')='2011')

It produces the required result, but using a Full Table Scan across all partitions. Very much better instead:

SQL> select sum(amount_sold) from sales_year where order_date between to_date('01.01.2011','dd.mm.yyyy') and to_date('31.12.2011','dd.mm.yyyy');

SUM(AMOUNT_SOLD)
----------------
      1825000000

Elapsed: 00:00:00.11
SQL> select plan_table_output from table(dbms_xplan.display_cursor);

PLAN_TABLE_OUTPUT
------------------------------------------------------------------------------------------------------
SQL_ID  6rwm3z7rhgmd6, child number 0
-------------------------------------
select sum(amount_sold) from sales_year where order_date between
to_date('01.01.2011','dd.mm.yyyy') and
to_date('31.12.2011','dd.mm.yyyy')

Plan hash value: 767904852

------------------------------------------------------------------------------------------------------
| Id  | Operation               | Name       | Rows  | Bytes | Cost (%CPU)| Time     | Pstart| Pstop |
------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT        |            |       |       |  1033 (100)|          |       |       |
|   1 |  SORT AGGREGATE         |            |     1 |    22 |            |          |       |       |
|   2 |   PARTITION RANGE SINGLE|            |   378K|  8128K|  1033  (16)| 00:00:01 |    27 |    27 |
|*  3 |    TABLE ACCESS FULL    | SALES_YEAR |   378K|  8128K|  1033  (16)| 00:00:01 |    27 |    27 |
------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   3 - filter(("ORDER_DATE">=TO_DATE(' 2011-01-01 00:00:00', 'syyyy-mm-dd hh24:mi:ss') AND
              "ORDER_DATE"<=TO_DATE(' 2011-12-31 00:00:00', 'syyyy-mm-dd hh24:mi:ss')))

The same result but much faster, scanning only one partition!

Conclusion: It is quite important to have no functions around the partition key in the WHERE-clause here. Personally, the first SQL looks easier to me and has less coding, but it is obviously not as good as the second. Might be worth to spend some time thinking and adding some more characters to the code to make Partition-Pruning possible. Don’t believe it, test it! With some big enough tables, I mean 🙂

,

14 Kommentare

Backup & Restore one Datafile in Parallel

multisection

A lesser known 11g New Feature is the option to backup and restore single large datafiles with multiple channels in parallel, which can speed up these processes dramatically. This posting is supposed to give an example for it.

SQL> select * from v$version;
BANNER
 --------------------------------------------------------------------------------
 Oracle Database 11g Enterprise Edition Release 11.2.0.3.0 - 64bit Production
 PL/SQL Release 11.2.0.3.0 - Production
 CORE    11.2.0.3.0    Production
 TNS for Linux: Version 11.2.0.3.0 - Production
 NLSRTL Version 11.2.0.3.0 - Production
SQL> select file#,bytes/1024/1024 as mb from v$datafile;
FILE#       MB
 ---------- ----------
 1                300
 2                200
 3                179
 4               2136

My demo system is on 11gR2, but the feature was there in 11gR1 already – it is easy to miss and just keep the old backup scripts in place like with 10g, though, where one channel could only read one datafile. bk is the same service that we have seen in a previous posting. I will now just backup & restore datafile 4 to show this can be done with two channels:

[oracle@uhesse1 ~]$ time rman target sys/oracle@uhesse1/bk cmdfile=backup_par.rmn
Recovery Manager: Release 11.2.0.3.0 - Production on Wed Dec 12 21:20:49 2012
Copyright (c) 1982, 2011, Oracle and/or its affiliates.  All rights reserved.
connected to target database: PRIMA (DBID=2003897072)
RMAN> configure device type disk parallelism 2;
 2> backup datafile 4 section size 1100m;
 3>
 using target database control file instead of recovery catalog
 old RMAN configuration parameters:
 CONFIGURE DEVICE TYPE DISK PARALLELISM 1 BACKUP TYPE TO BACKUPSET;
 new RMAN configuration parameters:
 CONFIGURE DEVICE TYPE DISK PARALLELISM 2 BACKUP TYPE TO BACKUPSET;
 new RMAN configuration parameters are successfully stored
Starting backup at 2012-12-12:21:20:50
 allocated channel: ORA_DISK_1
 channel ORA_DISK_1: SID=24 device type=DISK
 allocated channel: ORA_DISK_2
 channel ORA_DISK_2: SID=9 device type=DISK
 channel ORA_DISK_1: starting full datafile backup set
 channel ORA_DISK_1: specifying datafile(s) in backup set
 input datafile file number=00004 name=/home/oracle/prima/users01.dbf
 backing up blocks 1 through 140800
 channel ORA_DISK_1: starting piece 1 at 2012-12-12:21:20:51
 channel ORA_DISK_2: starting full datafile backup set
 channel ORA_DISK_2: specifying datafile(s) in backup set
 input datafile file number=00004 name=/home/oracle/prima/users01.dbf
 backing up blocks 140801 through 273408
 channel ORA_DISK_2: starting piece 2 at 2012-12-12:21:20:51
 channel ORA_DISK_2: finished piece 2 at 2012-12-12:21:21:46
 piece handle=/home/oracle/flashback/PRIMA/backupset/2012_12_12/o1_mf_nnndf_TAG20121212T212051_8dkss3kr_.bkp tag=TAG20121212T212051 comment=NONE
 channel ORA_DISK_2: backup set complete, elapsed time: 00:00:55
 channel ORA_DISK_1: finished piece 1 at 2012-12-12:21:22:06
 piece handle=/home/oracle/flashback/PRIMA/backupset/2012_12_12/o1_mf_nnndf_TAG20121212T212051_8dkss3bm_.bkp tag=TAG20121212T212051 comment=NONE
 channel ORA_DISK_1: backup set complete, elapsed time: 00:01:15
 Finished backup at 2012-12-12:21:22:06
Recovery Manager complete.
real    1m17.681s
 user    0m1.356s
 sys    0m0.129s

The script backup_par.rmn contains these lines:

[oracle@uhesse1 ~]$ cat backup_par.rmn
 configure device type disk parallelism 2;
 backup datafile 4 section size 1100m;

As you can see, the two channels were running in parallel, each taking about 1 minute to backup its section into a separate backupset. Also the restore can now be done in parallel for a single datafile:

[oracle@uhesse1 ~]$ time rman target sys/oracle@uhesse1/bk cmdfile=restore_par.rmn
Recovery Manager: Release 11.2.0.3.0 - Production on Wed Dec 12 21:23:28 2012
Copyright (c) 1982, 2011, Oracle and/or its affiliates.  All rights reserved.
 connected to target database: PRIMA (DBID=2003897072)
RMAN> configure device type disk parallelism 2;
 2> sql "alter database datafile 4 offline";
 3> restore datafile 4;
 4> recover datafile 4;
 5> sql "alter database datafile 4 online";
 6>
 7>
 using target database control file instead of recovery catalog
 old RMAN configuration parameters:
 CONFIGURE DEVICE TYPE DISK PARALLELISM 2 BACKUP TYPE TO BACKUPSET;
 new RMAN configuration parameters:
 CONFIGURE DEVICE TYPE DISK PARALLELISM 2 BACKUP TYPE TO BACKUPSET;
 new RMAN configuration parameters are successfully stored
sql statement: alter database datafile 4 offline
Starting restore at 2012-12-12:21:23:30
 allocated channel: ORA_DISK_1
 channel ORA_DISK_1: SID=9 device type=DISK
 allocated channel: ORA_DISK_2
 channel ORA_DISK_2: SID=24 device type=DISK
channel ORA_DISK_1: starting datafile backup set restore
 channel ORA_DISK_1: specifying datafile(s) to restore from backup set
 channel ORA_DISK_1: restoring datafile 00004 to /home/oracle/prima/users01.dbf
 channel ORA_DISK_1: restoring section 1 of 2
 channel ORA_DISK_1: reading from backup piece /home/oracle/flashback/PRIMA/backupset/2012_12_12/o1_mf_nnndf_TAG20121212T212051_8dkss3bm_.bkp
 channel ORA_DISK_2: starting datafile backup set restore
 channel ORA_DISK_2: specifying datafile(s) to restore from backup set
 channel ORA_DISK_2: restoring datafile 00004 to /home/oracle/prima/users01.dbf
 channel ORA_DISK_2: restoring section 2 of 2
 channel ORA_DISK_2: reading from backup piece /home/oracle/flashback/PRIMA/backupset/2012_12_12/o1_mf_nnndf_TAG20121212T212051_8dkss3kr_.bkp
 channel ORA_DISK_2: piece handle=/home/oracle/flashback/PRIMA/backupset/2012_12_12/o1_mf_nnndf_TAG20121212T212051_8dkss3kr_.bkp tag=TAG20121212T212051
 channel ORA_DISK_2: restored backup piece 2
 channel ORA_DISK_2: restore complete, elapsed time: 00:02:05
 channel ORA_DISK_1: piece handle=/home/oracle/flashback/PRIMA/backupset/2012_12_12/o1_mf_nnndf_TAG20121212T212051_8dkss3bm_.bkp tag=TAG20121212T212051
 channel ORA_DISK_1: restored backup piece 1
 channel ORA_DISK_1: restore complete, elapsed time: 00:02:16
 Finished restore at 2012-12-12:21:25:46
Starting recover at 2012-12-12:21:25:46
 using channel ORA_DISK_1
 using channel ORA_DISK_2
starting media recovery
 media recovery complete, elapsed time: 00:00:01
Finished recover at 2012-12-12:21:25:48
sql statement: alter database datafile 4 online
Recovery Manager complete.
real    2m20.137s
 user    0m1.229s
 sys    0m0.187s

This is the script I have used for the restore:

[oracle@uhesse1 ~]$ cat restore_par.rmn
 configure device type disk parallelism 2;
 sql "alter database datafile 4 offline";
 restore datafile 4;
 recover datafile 4;
 sql "alter database datafile 4 online";

Conclusion: Multisection backup & restore can be very useful for the processing of large (bigfile) datafiles with multiple channels in parallel. If you have not done it yet, you should definitely give it a try! As always: Don’t believe it, test it 🙂

Addendum: With 12c, this feature got enhanced to support also image copies.

, , ,

8 Kommentare

Why you should use Application Services with your Oracle Database

On a Single-Instance Oracle Database, Application Services offer benefits for Performance Monitoring & Tracing. That’s the focus of this posting. If you are on RAC respectively Data Guard already, you will use Services at least to provide Connect-Time Failover. You may find some additional useful things to do with them here. The playing field:

SQL> select * from v$version;

BANNER
--------------------------------------------------------------------------------
Oracle Database 11g Enterprise Edition Release 11.2.0.3.0 - 64bit Production
PL/SQL Release 11.2.0.3.0 - Production
CORE    11.2.0.3.0    Production
TNS for Linux: Version 11.2.0.3.0 - Production
NLSRTL Version 11.2.0.3.0 - Production

My demo DB has no Application Services yet. In the most simple case, there is one Application running and we take backups, so that gives us two services to introduce:

SQL> exec dbms_service.create_service('app1','app1')

PL/SQL procedure successfully completed.

SQL> exec dbms_service.create_service('bk','bk')

PL/SQL procedure successfully completed.

With Grid Infrastructure installed, we would use srvctl add service instead. The services are not yet started. Subsequently, an after startup on database trigger should do that.

SQL> exec dbms_service.start_service('app1')

PL/SQL procedure successfully completed.

SQL> exec dbms_service.start_service('bk')

PL/SQL procedure successfully completed.

SQL> grant dba to adam identified by adam;

Grant succeeded.

SQL> exec dbms_workload_repository.create_snapshot

PL/SQL procedure successfully completed.

SQL> select snap_id,to_char(begin_interval_time,'yyyy-mm-dd:hh24:mi:ss') 
from dba_hist_snapshot order by 1;  

   SNAP_ID TO_CHAR(BEGIN_INTER
---------- -------------------
     2 2012-01-18:15:09:15
     3 2012-01-18:15:20:30
     4 2012-01-19:12:51:40
     5 2012-03-19:12:03:03
     6 2012-10-31:14:59:25

The following uses Easy Connect (my host is named uhesse1; my Listener Port is 1521) to attach to the services:

SQL> connect adam/adam@uhesse1/app1
Connected.
SQL> alter session set workarea_size_policy=manual;

Session altered.

SQL> alter session set sort_area_size=100000000;

Session altered.

SQL> create table sales as select 
rownum as id,
mod(rownum,5) as channel_id,
mod(rownum,1000) as cust_id,
5000 as amount_sold,
sysdate as time_id
from dual connect by level<=1e6;    

Table created.

SQL> update sales set amount_sold=amount_sold*1;

1000000 rows updated.

SQL> commit;

Commit complete.

SQL> exit
Disconnected from Oracle Database 11g Enterprise Edition Release 11.2.0.3.0 - 64bit Production
With the Partitioning, OLAP and Data Mining options
[oracle@uhesse1 ~]$ rman target sys/oracle@uhesse1/bk

Recovery Manager: Release 11.2.0.3.0 - Production on Wed Oct 31 15:13:04 2012

Copyright (c) 1982, 2011, Oracle and/or its affiliates.  All rights reserved.

connected to target database: PRIMA (DBID=2003897072)

RMAN> backup database;

Starting backup at 31-OCT-12
using target database control file instead of recovery catalog
allocated channel: ORA_DISK_1
channel ORA_DISK_1: SID=50 device type=DISK
channel ORA_DISK_1: starting full datafile backup set
channel ORA_DISK_1: specifying datafile(s) in backup set
input datafile file number=00001 name=/home/oracle/prima/system01.dbf
input datafile file number=00002 name=/home/oracle/prima/sysaux01.dbf
input datafile file number=00003 name=/home/oracle/prima/undotbs01.dbf
input datafile file number=00004 name=/home/oracle/prima/users01.dbf
channel ORA_DISK_1: starting piece 1 at 31-OCT-12
channel ORA_DISK_1: finished piece 1 at 31-OCT-12
piece handle=/home/oracle/flashback/PRIMA/backupset/2012_10_31/o1_mf_nnndf_TAG20121031T151314_892dhwso_.bkp tag=TAG20121031T151314 comment=NONE
channel ORA_DISK_1: backup set complete, elapsed time: 00:00:15
channel ORA_DISK_1: starting full datafile backup set
channel ORA_DISK_1: specifying datafile(s) in backup set
including current control file in backup set
including current SPFILE in backup set
channel ORA_DISK_1: starting piece 1 at 31-OCT-12
channel ORA_DISK_1: finished piece 1 at 31-OCT-12
piece handle=/home/oracle/flashback/PRIMA/backupset/2012_10_31/o1_mf_ncsnf_TAG20121031T151314_892djcbb_.bkp tag=TAG20121031T151314 comment=NONE
channel ORA_DISK_1: backup set complete, elapsed time: 00:00:01
Finished backup at 31-OCT-12

RMAN> exit

Recovery Manager complete.
[oracle@uhesse1 ~]$ sqlplus / as sysdba

SQL*Plus: Release 11.2.0.3.0 Production on Wed Oct 31 15:13:41 2012

Copyright (c) 1982, 2011, Oracle.  All rights reserved.

Connected to:
Oracle Database 11g Enterprise Edition Release 11.2.0.3.0 - 64bit Production
With the Partitioning, OLAP and Data Mining options

SQL> exec dbms_workload_repository.create_snapshot

PL/SQL procedure successfully completed.

SQL> select snap_id,to_char(begin_interval_time,'yyyy-mm-dd:hh24:mi:ss') 
from dba_hist_snapshot order by 1;   

   SNAP_ID TO_CHAR(BEGIN_INTER
---------- -------------------
     2 2012-01-18:15:09:15
     3 2012-01-18:15:20:30
     4 2012-01-19:12:51:40
     5 2012-03-19:12:03:03
     6 2012-10-31:14:59:25
     7 2012-10-31:15:06:13

6 rows selected.

Some „Application“ load was followed by an RMAN backup. We can now differentiate those loads. The AWR report for the last two snapshots show this section:

We can tell from the low values of DB Time for the bk service in relation to the app1 service that the (Online-)Backup has had almost no impact on performance for end users here. Also, we have v$-views for services:

SQL> set lines 200
set pages 300
col service_name for a10
select service_name,event,time_waited 
from v$service_event natural join v$event_name 
where service_name in ('app1','bk') 
and wait_class<>'Idle' 
order by 1,3; 

SERVICE_NA EVENT                                                            TIME_WAITED
---------- ---------------------------------------------------------------- -----------
app1       control file sequential read                                               0
app1       SQL*Net message to client                                                  0
app1       db file single write                                                       1
app1       db file scattered read                                                     1
app1       log file sync                                                              1
app1       control file parallel write                                                1
app1       direct path write                                                          2
app1       direct path sync                                                           3
app1       Data file init write                                                       3
app1       Disk file operations I/O                                                   4
app1       buffer busy waits                                                          5
app1       free buffer waits                                                         13
app1       log file switch (private strand flush incomplete)                         14
app1       db file sequential read                                                   26
app1       log file switch completion                                                28
app1       log buffer space                                                        1635
bk       Parameter File I/O                                                           0
bk       db file scattered read                                                       0
bk       SQL*Net message to client                                                    0
bk       SQL*Net break/reset to client                                                0
bk       db file single write                                                         0
bk       db file sequential read                                                      2
bk       control file parallel write                                                  7
bk       control file single write                                                    8
bk       Disk file operations I/O                                                    12
bk       control file sequential read                                                18
bk       events in waitclass Other                                                  217
bk       RMAN backup & recovery I/O                                                 757

28 rows selected.

SQL> select service_name,value 
from v$service_stats 
where service_name in ('app1','bk') 
and stat_name='physical reads';    

SERVICE_NA    VALUE
---------- ----------
app1            13422
bk                351

There are completely different Top Wait-Events for the two services. ‚physical reads‘ was just one example from the hundreds of available stats. In the very same manner, multiple applications running on the same DB could be differentiated. Furthermore, we can switch on tracing now for only certain services resp. applications:

SQL> exec dbms_monitor.serv_mod_act_trace_enable('app1')

PL/SQL procedure successfully completed.

SQL> connect adam/adam@uhesse1/app1
Connected.
SQL> select count(*) from sales;

  COUNT(*)
----------
   1000000

SQL> select distinct channel_id from sales;

CHANNEL_ID
----------
     1
     2
     4
     3
     0

SQL> connect / as sysdba
Connected.
SQL> exec dbms_monitor.serv_mod_act_trace_disable('app1')

PL/SQL procedure successfully completed.

This kind of service tracing produces potentially many trace files that we can consolidate (and identify) with trcsess like this:

[oracle@uhesse1 trace]$ trcsess output=app1.trc service=app1 *.trc

Afterwards, we can get a better readable output of the trace file with tkprof as usual, showing all the statements of the applications together with their execution plans.

Conclusion: You will always implement Application Services with RAC respectively Data Guard. For Single-Instance, you should use them also because

1) You may use RAC resp. Data Guard in the future and then you have everything in place already

2) You can do Performance Monitoring with a finer granule (on the Application layer) with them

3) You can trace with a finer granule as well

, , , , ,

16 Kommentare