Continuing my previous post, here I demonstrate using V$SQLSTATS.PX_SERVERS_EXECUTIONS and a couple of issues around it.
I have restarted the database.
[Note : To understand why the executions took 16 PX Servers inspite of the degree on table being 1, see this post]
So we see that PX_SERVERS_EXECUTIONS shows cumulative statistics. Let's try a slight twist.
Because I set PARALLEL_MAX_SERVERS to 8, my query on Large_Table could take only 8 PX Servers at the next execution. V$SQLSTATS.PX_SERVERS_EXECUTIONS now shows a cumulative count of 40 for 3 executions. There is no way to determine how many PX Servers were used in each of the 3 executions, because the history of executions is not maintained.
(In my controlled experiment, we know, by deduction, that the 3rd execution took 8 PX Servers simply because we know already that the first 2 executions took a cumulative count of 32 PX Servers -- by deducting 32 from 40 to get 8 for the 3rd execution)
What happens if the SQL is invalidated ?
The ALTER TABLE, being a DDL, had invalidated the query on Large_Table. So, V$SQLSTATS also got reset. Therefore, EXECUTIONS reset to 1 and PX_SERVES_EXECUTIONS got reset to 8.
.
.
.
I have restarted the database.
[oracle@localhost ~]$ sqlplus hemant/hemant SQL*Plus: Release 11.2.0.2.0 Production on Fri Mar 13 22:49:20 2015 Copyright (c) 1982, 2010, Oracle. All rights reserved. Connected to: Oracle Database 11g Enterprise Edition Release 11.2.0.2.0 - Production With the Partitioning, OLAP, Data Mining and Real Application Testing options HEMANT>show parameter cpu NAME TYPE VALUE ------------------------------------ ----------- ------------------------------ cpu_count integer 4 parallel_threads_per_cpu integer 4 resource_manager_cpu_allocation integer 4 HEMANT>select degree from user_tables where table_name = 'LARGE_TABLE'; DEGREE ---------------------------------------- 1 HEMANT>select /*+ PARALLEL */ count(*) from Large_Table; COUNT(*) ---------- 4802944 HEMANT>select executions, px_servers_executions, sql_fulltext 2 from v$sqlstats 3 where sql_id = '8b0ybuspqu0mm'; EXECUTIONS PX_SERVERS_EXECUTIONS SQL_FULLTEXT ---------- --------------------- -------------------------------------------------------------------------------- 1 16 select /*+ PARALLEL */ count(*) from Large_Table HEMANT> HEMANT>select /*+ PARALLEL */ count(*) from Large_Table; COUNT(*) ---------- 4802944 HEMANT>select executions, px_servers_executions, sql_fulltext 2 from v$sqlstats 3 where sql_id = '8b0ybuspqu0mm'; EXECUTIONS PX_SERVERS_EXECUTIONS SQL_FULLTEXT ---------- --------------------- -------------------------------------------------------------------------------- 2 32 select /*+ PARALLEL */ count(*) from Large_Table HEMANT>
[Note : To understand why the executions took 16 PX Servers inspite of the degree on table being 1, see this post]
So we see that PX_SERVERS_EXECUTIONS shows cumulative statistics. Let's try a slight twist.
HEMANT>connect / as sysdba Connected. SYS>alter system set parallel_max_servers=8; System altered. SYS>connect hemant/hemant Connected. HEMANT>select /*+ PARALLEL */ count(*) from Large_Table; COUNT(*) ---------- 4802944 HEMANT>select executions, px_servers_executions, sql_fulltext 2 from v$sqlstats 3 where sql_id = '8b0ybuspqu0mm'; EXECUTIONS PX_SERVERS_EXECUTIONS SQL_FULLTEXT ---------- --------------------- -------------------------------------------------------------------------------- 3 40 select /*+ PARALLEL */ count(*) from Large_Table HEMANT>
Because I set PARALLEL_MAX_SERVERS to 8, my query on Large_Table could take only 8 PX Servers at the next execution. V$SQLSTATS.PX_SERVERS_EXECUTIONS now shows a cumulative count of 40 for 3 executions. There is no way to determine how many PX Servers were used in each of the 3 executions, because the history of executions is not maintained.
(In my controlled experiment, we know, by deduction, that the 3rd execution took 8 PX Servers simply because we know already that the first 2 executions took a cumulative count of 32 PX Servers -- by deducting 32 from 40 to get 8 for the 3rd execution)
What happens if the SQL is invalidated ?
HEMANT>alter table large_table parallel 4; Table altered. HEMANT>select /*+ PARALLEL */ count(*) from Large_Table; COUNT(*) ---------- 4802944 HEMANT>select executions, px_servers_executions, sql_fulltext 2 from v$sqlstats 3 where sql_id = '8b0ybuspqu0mm'; EXECUTIONS PX_SERVERS_EXECUTIONS SQL_FULLTEXT ---------- --------------------- -------------------------------------------------------------------------------- 1 8 select /*+ PARALLEL */ count(*) from Large_Table HEMANT>
The ALTER TABLE, being a DDL, had invalidated the query on Large_Table. So, V$SQLSTATS also got reset. Therefore, EXECUTIONS reset to 1 and PX_SERVES_EXECUTIONS got reset to 8.
.
.
.
1 comment:
It could be a little easier if we can use real time sql monitor(>=11g):
https://gist.github.com/xtender/c024cd87ff86cb213c94
Post a Comment