Skip to content

Commit 46059bb

Browse files
initial commit
1 parent b650a1f commit 46059bb

10 files changed

+4169
-1
lines changed

README.md

+122-1
Original file line numberDiff line numberDiff line change
@@ -1 +1,122 @@
1-
# bvc
1+
This is a set of scripts whose purpose is mainly to check quickly and easily whether the database clients are using bind variables or not.
2+
3+
### bvc_check.sql
4+
5+
The most convenient script is bvc_check.sql, that reads the statements text from gv$sql and then reports the ones that have the same _bound statement_ (which is simply the statement text whose literals are replaced with bind variables, normalized in lowercase, with redundant white space removed, etc).
6+
7+
Here's an example of the bvc_check.sql script output:
8+
9+
```
10+
------------------
11+
statements count : 0000000003
12+
bound : select*from t where x=:n
13+
example 1: select * from t where x = 2
14+
example 2: select * from t where x = 3
15+
------------------
16+
```
17+
18+
This shows that there are three statements that map to the same bound statement "select*from t where x=:n"; two examples are provided as output.
19+
20+
This script does not need any server-side install, which is of course a definitive plus when investigating production since normally we are not allowed to install anything there. You only need select privileges on gv$sql, gv$sqltext_with_newlines and dba_users; just run bvc_check.sql inside sqlplus and then inspect the output bvc_check.lst file.
21+
22+
Caveat: the full-scan of gv$sql is quite heavy on latches - this may impact the performance of a system that is already heavy contending on library cache latches, so check in production first for this kind of latch contention. It is anyway a lesser problem in recent Oracle versions.
23+
24+
If all you need is a simple script to check for bind variables - you can stop reading here.
25+
26+
### bvc_tokenizer_pkg.sql: Bound Statement calculator
27+
28+
The script bvc_tokenizer_pkg.sql installs the package bvc_tokenizer_pkg server-side; this package provides a stored function, bound_stmt(), which is the workhorse that calculates the bound statement. For example:
29+
30+
```
31+
SQL> select bvc_tokenizer_pkg.bound_stmt ('select * from t where x = 2') as bound from dual;
32+
33+
BOUND
34+
------------------------------
35+
select*from t where x=:n
36+
```
37+
38+
This stored function is similar to the Tom Kyte's function [remove_constants](http://asktom.oracle.com/pls/ask/f?p=4950:8:::::F4950_P8_DISPLAYID:1163635055580) but much more sophisticated. Check the bvc_tokenizer_pkg.sql header for more information.
39+
40+
This stored function allows for very intriguing analyses.
41+
42+
#### Flexible analysis of bind variables usage
43+
44+
First, obviously, we can easily make (almost)the same analysis that bvc_check.sql makes:
45+
46+
```
47+
select bvc_tokenizer_pkg.bound_stmt(sql_text) bound, count(*) cnt
48+
from (
49+
select distinct sql_text
50+
from gv$sql
51+
where parsing_user_id not in (select user_id from dba_users where username in ('SYS','SYSTEM'))
52+
)
53+
group by bvc_tokenizer_pkg.bound_stmt(sql_text)
54+
having count(*) > 1
55+
order by cnt desc;
56+
57+
BOUND CNT
58+
-------------------------------------------------- ----------
59+
select*from t where x=:n 5
60+
select*from t where to_char(x)=:s 4
61+
```
62+
63+
The advantage over bvc_check.sql is flexibility, since we can very easily adapt the mining SQL to our needs; examples of frequently occurring scenarios are investigating only statements parsed by certain users (gv$sql.parsing_user_id), or whose executions is above a certain threshold, or joining other gv$ views to enrich the mined information.
64+
65+
#### Grouping execution statistics by bound statement
66+
67+
The bound_stmt() stored function has other uses besides checking for bind variables. The most interesting one is to properly group execution statistics for statements that are not using bind variables (which could be made for perfectly sound reasons: literals are not always evil ;). For instance, if your clients submit 20 statements that map to the same bound statement, each one consuming only 1% of a resource, it's way too easy to overlook the importance of the statement; but if you group the resource by bound statement, it is quite impossible to miss a whopping 20%.
68+
69+
Here is an example of this technique:
70+
71+
```
72+
select bvc_tokenizer_pkg.bound_stmt(sql_text) bound,
73+
sum(elapsed_time) elapsed_time
74+
from v$sql
75+
group by bvc_tokenizer_pkg.bound_stmt(sql_text)
76+
order by elapsed_time desc;
77+
BOUND ELAPSED_TIME
78+
-------------------------------------------------- ------------
79+
declare job binary_integer:=:b;next_date date:=:b; 15707151
80+
broken boolean:=false;begin wwv_flow_mail.push_que
81+
ue(wwv_flow_platform.get_preference(:s),wwv_flow_p
82+
latform.get_preference(:s));:b:=next_date;if broke
83+
n then:b:=:n;else:b:=:n;end if;end;
84+
85+
select table_objno,primary_instance,secondary_inst 4531685
86+
ance,owner_instance from sys.aq$_queue_table_affin
87+
ities a where a.owner_instance<>:b and dbms_aqadm_
88+
syscalls.get_owner_instance(a.primary_instance,a.s
89+
econdary_instance,a.owner_instance)=:b order by ta
90+
ble_objno for update of a.owner_instance skip lock
91+
ed
92+
```
93+
94+
### bvc_tokenizer_pkg.sql: Statement Tokenizer
95+
96+
The bvc_tokenizer_pkg.sql implements also a SQL tokenizer (a routine that breaks a SQL statement into its tokens). For example:
97+
98+
```
99+
SQL> exec bvc_tokenizer_pkg.debug_print_tokens ('select /*+ first_rows */ a from t where x + +1.e-123 > :ph');
100+
101+
keyword "select"
102+
conn " "
103+
hint "/*+ first_rows */"
104+
conn " "
105+
ident "a"
106+
conn " "
107+
keyword "from"
108+
conn " "
109+
ident "t"
110+
conn " "
111+
keyword "where"
112+
conn " "
113+
ident "x"
114+
conn " + "
115+
number "+1.e-123"
116+
conn " > "
117+
bind ":ph"
118+
```
119+
120+
This routine is used by the bound_stmt() stored function discussed above; the latter simply substitutes each number/string/bind token with a bind variable and then concatenates the tokens back.
121+
122+
Of course, the tokenizer routine might be easily used to implement a SQL pretty printer - something I might implement in the future.

README.txt

+5
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,5 @@
1+
1) Put all the scripts in the same common directory
2+
2) Change the current directory to the common directory
3+
3) Connect to the database by sqlplus from the common directory
4+
4) Run the chosen script (for example, @bvc_check.sql)
5+

bvc_check.sql

+246
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,246 @@
1+
--------------------------------------------------------------------------------
2+
-- Bind Variables Checker: install-free basic checking script.
3+
--
4+
-- This script will dump all the statements whose bound statement is the same,
5+
-- that is, all statements that are using literals instead of bind variables
6+
-- and that can potentially benefit from turning literals into bind variables.
7+
--
8+
-- Note: only the first (about) 32K characters of the SQL text are considered due to pl/sql
9+
-- limitations. Any statement longer than 32K will be signaled with a warning.
10+
-- These statements might produce false positives or false negatives, depending on
11+
-- whether the two bounded version of the two fragments before and after the truncation point
12+
-- are the same or not. Of course, statements longer than 32K are rare and usually
13+
-- do not need to use bind variables.
14+
--
15+
-- Every statement is dumped together with the number of versions found in the library cache
16+
-- (highest version count first) and two examples, both with their hash_value (or sql_id if available).
17+
--
18+
-- Run with a user with SELECT privileges on gv$sql, gv$sqltext_with_newlines and dba_users.
19+
--
20+
-- See bvc_tokenizer_pkg.sql for further comments and documentation
21+
--
22+
-- Author: Alberto Dell'Era
23+
-- Copyright: (c) 2003 - 2017 Alberto Dell'Era http://www.adellera.it
24+
--------------------------------------------------------------------------------
25+
define BVC_CHECK_VERSION="1.2.2 28-January-2016"
26+
27+
set null "" trimspool on define on escape off pages 50000 tab off arraysize 100
28+
set echo off verify off feedback off termout on timing off
29+
30+
define normalize_numbers_in_ident=N
31+
define normalize_partition_names=N
32+
define strip_hints=N
33+
define deterministic=' '
34+
define spool_file_name=bvc_check.lst
35+
36+
set serveroutput on
37+
set lines 300
38+
39+
alter session set cursor_sharing=exact;
40+
41+
-- set version defines, get parameters
42+
variable v_db_major_version number
43+
variable V_DB_VERSION varchar2(20 char)
44+
variable V_DB_VERSION_COMPAT varchar2(20 char)
45+
variable DB_NAME varchar2(30 char)
46+
variable INSTANCE_NAME varchar2(30 char)
47+
declare /* bvc_marker */
48+
l_dummy_bi1 binary_integer;
49+
l_dummy_bi2 binary_integer;
50+
begin
51+
sys.dbms_utility.db_version (:V_DB_VERSION, :V_DB_VERSION_COMPAT);
52+
:v_db_major_version := to_number (substr (:V_DB_VERSION, 1, instr (:V_DB_VERSION, '.') - 1));
53+
l_dummy_bi1 := sys.dbms_utility.get_parameter_value ('db_name' , l_dummy_bi2, :DB_NAME );
54+
l_dummy_bi1 := sys.dbms_utility.get_parameter_value ('instance_name', l_dummy_bi2, :INSTANCE_NAME);
55+
end;
56+
/
57+
58+
set echo on
59+
60+
-- set version-dependent commenting-out defines
61+
define COMM_IF_LT_10G="error"
62+
define COMM_IF_GT_9I="error"
63+
col COMM_IF_LT_10G noprint new_value COMM_IF_LT_10G
64+
col COMM_IF_GT_9I noprint new_value COMM_IF_GT_9I
65+
select /* bvc_marker */
66+
case when :v_db_major_version < 10 then '--' else '' end COMM_IF_LT_10G,
67+
case when :v_db_major_version > 9 then '--' else '' end COMM_IF_GT_9I
68+
from dual;
69+
70+
set echo off
71+
72+
prompt Fetching statements. This might take a while, please wait ...
73+
74+
variable BVC_CHECK_NUM_STMTS number
75+
76+
spool &spool_file_name.
77+
78+
prompt normalize_numbers_in_ident=&&normalize_numbers_in_ident.; normalize_partition_names=&&normalize_partition_names.; strip_hints=&&strip_hints.
79+
80+
declare /* bvc_marker */
81+
@@bvc_tokenizer_head_vars.sql
82+
@@bvc_tokenizer_body_vars.sql
83+
-- stmt -> already checked
84+
type t_stmt_seen is table of number index by varchar2(32767);
85+
l_stmt_seen t_stmt_seen;
86+
-- bound stmt -> counts
87+
type t_bound_counts is table of number index by varchar2(32767);
88+
l_bound_counts t_bound_counts;
89+
-- bound stmt -> stmt examples
90+
type t_examples_elem is record (
91+
text long,
92+
parsing_user_id number,
93+
&COMM_IF_GT_9I. hash_value number
94+
&COMM_IF_LT_10G. sql_id v$sql.sql_id%type
95+
);
96+
type t_examples is table of t_examples_elem index by varchar2(32767);
97+
l_example_1 t_examples;
98+
l_example_2 t_examples;
99+
-- counts -> bound stmt
100+
type t_counts_bound is table of varchar2(32767) index by varchar2(20);
101+
l_counts_bound t_counts_bound;
102+
-- limit
103+
l_sql_text_max_length int := 32767; -- 20160128
104+
-- misc
105+
l_bound long;
106+
l_counts number;
107+
l_num_stmts number := 0;
108+
l_count_ext varchar2 (20 char);
109+
l_db_name varchar2 (200 char);
110+
l_sql_text long;
111+
l_sql_text_too_long boolean;
112+
l_parsing_username_1 dba_users.username%type;
113+
l_parsing_username_2 dba_users.username%type;
114+
115+
@@bvc_tokenizer_body.sql
116+
-- line-wrapper printer
117+
procedure check_print (p_msg varchar2)
118+
is
119+
begin
120+
print (p_msg);
121+
end;
122+
begin
123+
-- initialize bvc engine
124+
populate_g_keywords;
125+
126+
-- read statements text from v$sql
127+
for stmt in (select /*+ cursor_sharing_exact bvc_marker */
128+
distinct inst_id, address, hash_value, sql_text, lengthb(sql_text) as sql_text_lengthb, parsing_user_id
129+
&COMM_IF_LT_10G. , sql_id
130+
from sys.gv_$sql
131+
where executions > 0
132+
and lengthb(sql_text) > 10
133+
and sql_text not like '% bvc_marker %'
134+
and sql_text not like '%xplan_exec_marker%'
135+
and not (module = 'DIO' and action = 'DIO') -- statements from diagnosing tool
136+
and parsing_user_id not in (select user_id from dba_users where username in ('SYS', 'SYSTEM', 'SYSMAN', 'DBSNMP', 'CTXSYS', 'MDSYS', 'ORDSYS', 'ORACLE_OCM') )
137+
)
138+
loop
139+
l_sql_text_too_long := false;
140+
l_sql_text := null;
141+
142+
if 1=0 /* 20160128: v$sql.sql_text contains wrong newlines, comments out statement */ and stmt.sql_text_lengthb <= 990 then -- max(lengthb(sql_text)) looks like 999, not 1000
143+
l_sql_text := stmt.sql_text;
144+
else
145+
-- get full stmt text if longer than 1000 chars
146+
for x in (select /*+ bvc_marker */ sql_text, lengthb(sql_text) as sql_text_lengthb
147+
from sys.gv_$sqltext_with_newlines
148+
where inst_id = stmt.inst_id
149+
and address = stmt.address
150+
and hash_value = stmt.hash_value
151+
order by piece)
152+
loop
153+
if nvl(lengthb(l_sql_text),0) + x.sql_text_lengthb >= l_sql_text_max_length then
154+
l_sql_text_too_long := true;
155+
exit;
156+
else
157+
l_sql_text := l_sql_text || x.sql_text;
158+
end if;
159+
end loop;
160+
end if;
161+
162+
if l_sql_text_too_long then
163+
check_print ('WARNING: statement with hash="'||stmt.hash_value||'" is longer than '||l_sql_text_max_length||'. '
164+
||chr(10)||' Only the first '||l_sql_text_max_length||' will be considered by, with possible false positives or negatives.'
165+
||chr(10)||' First few chars: "'|| substr (l_sql_text, 1, 100) ||'"');
166+
end if;
167+
168+
if l_sql_text is not null -- it might happen for inconsistencies between gv$sql and gv$sqltext_with_newlines
169+
and not l_stmt_seen.exists( l_sql_text ) then
170+
l_stmt_seen ( l_sql_text ) := 1;
171+
l_bound := bound_stmt ( l_sql_text, p_normalize_numbers_in_ident => '&&normalize_numbers_in_ident.', p_normalize_partition_names => '&&normalize_partition_names.', p_strip_hints => '&&strip_hints.' );
172+
if l_bound is null then -- bug
173+
check_print( 'bound stmt is null for hash="'||stmt.hash_value||'" - sql_text="'||l_sql_text||'"' );
174+
elsif l_bound = '**bound statement too long**' then
175+
check_print( 'bound stmt too long for hash="'||stmt.hash_value||'" - sql_text="'||l_sql_text||'"' );
176+
else
177+
if not l_bound_counts.exists ( l_bound ) then
178+
l_bound_counts ( l_bound ) := 1;
179+
l_example_1 ( l_bound ).text := l_sql_text;
180+
l_example_1 ( l_bound ).parsing_user_id := stmt.parsing_user_id;
181+
&COMM_IF_GT_9I. l_example_1 ( l_bound ).hash_value := stmt.hash_value;
182+
&COMM_IF_LT_10G. l_example_1 ( l_bound ).sql_id := stmt.sql_id;
183+
else
184+
l_counts := l_bound_counts ( l_bound );
185+
l_bound_counts ( l_bound ) := l_counts + 1;
186+
if l_counts = 1 then
187+
l_example_2 ( l_bound ).text := l_sql_text;
188+
l_example_2 ( l_bound ).parsing_user_id := stmt.parsing_user_id;
189+
&COMM_IF_GT_9I. l_example_2 ( l_bound ).hash_value := stmt.hash_value;
190+
&COMM_IF_LT_10G. l_example_2 ( l_bound ).sql_id := stmt.sql_id;
191+
end if;
192+
end if;
193+
end if;
194+
end if;
195+
end loop;
196+
197+
-- get all stmts whose count > 1, in order of counts
198+
l_bound := l_bound_counts.first;
199+
loop
200+
exit when l_bound is null;
201+
l_counts := l_bound_counts ( l_bound );
202+
if l_counts >= 2 then
203+
l_num_stmts := l_num_stmts + 1;
204+
l_counts_bound ( to_char (l_counts, '0000000000') || '_' || l_num_stmts ) := l_bound;
205+
end if;
206+
l_bound := l_bound_counts.next ( l_bound );
207+
end loop;
208+
:BVC_CHECK_NUM_STMTS := l_num_stmts;
209+
210+
-- print statements in reverse order of counts
211+
select /*+ cursor_sharing_exact bvc_marker */ sys_context ('USERENV', 'DB_NAME') into l_db_name from dual;
212+
check_print ('-----------------------------------------------------------------------------');
213+
check_print ('Output of Bind Variables Checker (basic script), version &BVC_CHECK_VERSION.');
214+
check_print ('(c) 2003 - 2016 Alberto Dell''Era http://www.adellera.it');
215+
check_print ('Dumped on '||to_char(sysdate, 'yyyy/mm/dd hh24:mi:ss') || ', db_name="'||:DB_NAME||'", instance_name="'||:INSTANCE_NAME||'"');
216+
check_print ('-----------------------------------------------------------------------------');
217+
check_print ('Following '||l_num_stmts||' bound statements are not using bind variables:');
218+
check_print (' ');
219+
l_count_ext := l_counts_bound.last;
220+
loop
221+
exit when l_count_ext is null;
222+
l_bound := l_counts_bound (l_count_ext);
223+
check_print ('------------------');
224+
check_print ('statements count : ' || ltrim ( trim( substr (l_count_ext, 1, instr (l_count_ext, '_')-1 ) ) , '0') );
225+
&COMM_IF_GT_9I. check_print ('example 1/2 hash values = ' || l_example_1 ( l_bound ).hash_value || ' / ' || l_example_2 ( l_bound ).hash_value);
226+
&COMM_IF_LT_10G. check_print ('example 1/2 sql_id = ' || l_example_1 ( l_bound ).sql_id || ' / ' || l_example_2 ( l_bound ).sql_id);
227+
select username into l_parsing_username_1 from dba_users where user_id = l_example_1 ( l_bound ).parsing_user_id;
228+
select username into l_parsing_username_2 from dba_users where user_id = l_example_2 ( l_bound ).parsing_user_id;
229+
check_print ('example 1/2 parsing username = ' || l_parsing_username_1 || ' / ' || l_parsing_username_2);
230+
check_print ('bound : ' || l_bound);
231+
check_print ('example 1: ' || l_example_1 ( l_bound ).text );
232+
check_print ('example 2: ' || l_example_2 ( l_bound ).text );
233+
l_count_ext := l_counts_bound.prior ( l_count_ext );
234+
end loop;
235+
236+
end;
237+
/
238+
239+
spool off
240+
241+
define BVC_CHECK_NUM_STMTS="*error*"
242+
col BVC_CHECK_NUM_STMTS noprint new_value BVC_CHECK_NUM_STMTS
243+
select /*+ cursor_sharing_exact bvc_marker */ trim(:BVC_CHECK_NUM_STMTS) as BVC_CHECK_NUM_STMTS from dual;
244+
245+
prompt Fetch complete; spool file "&spool_file_name." produced with &BVC_CHECK_NUM_STMTS. statements.
246+

bvc_check_test.sql

+12
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,12 @@
1+
2+
3+
alter system flush shared_pool;
4+
5+
drop table t;
6+
create table t (x int);
7+
8+
select * from t where x = 1;
9+
select * from t where x = 2;
10+
select * from t where x = 3;
11+
12+
@bvc_check.sql

0 commit comments

Comments
 (0)