File: opt_trace_selectivity.test

package info (click to toggle)
mariadb 1%3A11.8.3-1
  • links: PTS, VCS
  • area: main
  • in suites: forky, sid
  • size: 772,520 kB
  • sloc: ansic: 2,414,714; cpp: 1,791,394; asm: 381,336; perl: 62,905; sh: 49,647; pascal: 40,897; java: 39,363; python: 20,791; yacc: 20,432; sql: 17,907; xml: 12,344; ruby: 8,544; cs: 6,542; makefile: 6,145; ada: 1,879; lex: 1,193; javascript: 996; objc: 80; tcl: 73; awk: 46; php: 22
file content (86 lines) | stat: -rw-r--r-- 3,191 bytes parent folder | download | duplicates (2)
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
--source include/have_sequence.inc
--source include/not_embedded.inc

#
# Test changes in calculate_cond_selectivity_for_table()
#
create or replace table t1 (a int, b int, c int, key(a,c), key(b,c), key (c,b)) engine=aria;
insert into t1 select seq/100+1, mod(seq,10), mod(seq,15) from seq_1_to_10000;
insert into t1 select seq/100+1, mod(seq,10), 10 from seq_1_to_1000;
optimize table t1;

select count(*) from t1 where a=2;
select count(*) from t1 where b=5;
select count(*) from t1 where c=5;
select count(*) from t1 where c=10;
select count(*) from t1 where a=2 and b=5;
select count(*) from t1 where c=10 and b=5;
select count(*) from t1 where c=5 and b=5;

set optimizer_trace="enabled=on";
select count(*) from t1 where a=2 and b=5 and c=10;

set @trace=(select trace from INFORMATION_SCHEMA.OPTIMIZER_TRACE);

# The second JSON_EXTRACT is for --view-protocol which wraps every select:
select 
  JSON_DETAILED(
    JSON_EXTRACT(
      JSON_EXTRACT(@trace, '$**.considered_execution_plans'),
      '$[0]'
    )
  ) as JS;

select JSON_DETAILED(JSON_EXTRACT(@trace, '$**.selectivity_for_indexes')) as JS;

select count(*) from t1 where a=2 and b=5 and c=5;
set @trace=(select trace from INFORMATION_SCHEMA.OPTIMIZER_TRACE);

# The second JSON_EXTRACT is for --view-protocol which wraps every select:
select 
  JSON_DETAILED(
    JSON_EXTRACT(
      JSON_EXTRACT(@trace, '$**.considered_execution_plans'),
      '$[0]'
    )
  ) as JS;
select JSON_DETAILED(JSON_EXTRACT(@trace, '$**.selectivity_for_indexes')) as JS;

--echo # Ensure that we only use selectivity from non used index for simple cases


select count(*) from t1 where (a=2 and b= 5);
select JSON_DETAILED(JSON_EXTRACT(trace, '$**.selectivity_for_indexes')) as JS
from INFORMATION_SCHEMA.OPTIMIZER_TRACE;

--echo # All of the following should have selectivity=1 for index 'b'
select count(*) from t1 where (a=2 and b between 0 and 100);
select JSON_DETAILED(JSON_EXTRACT(trace, '$**.selectivity_for_indexes')) as JS
from INFORMATION_SCHEMA.OPTIMIZER_TRACE;

select count(*) from t1 where (a in (2,3) and b between 0 and 100);
select JSON_DETAILED(JSON_EXTRACT(trace, '$**.selectivity_for_indexes')) as JS
from INFORMATION_SCHEMA.OPTIMIZER_TRACE;

select count(*) from t1 where (a>2 and b between 0 and 100);
select JSON_DETAILED(JSON_EXTRACT(trace, '$**.selectivity_for_indexes')) as JS
from INFORMATION_SCHEMA.OPTIMIZER_TRACE;

select count(*) from t1 where (a>=2 and b between 0 and 100);
select JSON_DETAILED(JSON_EXTRACT(trace, '$**.selectivity_for_indexes')) as JS
from INFORMATION_SCHEMA.OPTIMIZER_TRACE;

select count(*) from t1 where (a<=2 and b between 0 and 100);
select JSON_DETAILED(JSON_EXTRACT(trace, '$**.selectivity_for_indexes')) as JS
from INFORMATION_SCHEMA.OPTIMIZER_TRACE;

select count(*) from t1 where (a<2 and b between 0 and 100);
select JSON_DETAILED(JSON_EXTRACT(trace, '$**.selectivity_for_indexes')) as JS
from INFORMATION_SCHEMA.OPTIMIZER_TRACE;

select count(*) from t1 where (a between 2 and 3 and b between 0 and 100);
select JSON_DETAILED(JSON_EXTRACT(trace, '$**.selectivity_for_indexes')) as JS
from INFORMATION_SCHEMA.OPTIMIZER_TRACE;

drop table t1;
set optimizer_trace='enabled=off';