summaryrefslogtreecommitdiff
path: root/sql-bench/test-table-elimination.sh
blob: 7772cab42b0ac02e602ac1020f5dea53b2190c20 (plain)
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
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
#!/usr/bin/perl
# Test of table elimination feature

use Cwd;
use DBI;
use Getopt::Long;
use Benchmark;

$opt_loop_count=100000;
$opt_medium_loop_count=10000;
$opt_small_loop_count=100;

$pwd = cwd(); $pwd = "." if ($pwd eq '');
require "$pwd/bench-init.pl" || die "Can't read Configuration file: $!\n";

if ($opt_small_test)
{
  $opt_loop_count/=10;
  $opt_medium_loop_count/=10;
  $opt_small_loop_count/=10;
}

print "Testing table elimination feature\n";
print "The test table has $opt_loop_count rows.\n\n";

# A query to get the recent versions of all attributes:
$select_current_full_facts="
  select 
    F.id, A1.attr1, A2.attr2
  from 
    elim_facts F 
    left join elim_attr1 A1 on A1.id=F.id
    left join elim_attr2 A2 on A2.id=F.id and 
                               A2.fromdate=(select MAX(fromdate) from
                                            elim_attr2 where id=A2.id);
";
$select_current_full_facts="
  select 
    F.id, A1.attr1, A2.attr2
  from 
    elim_facts F 
    left join elim_attr1 A1 on A1.id=F.id
    left join elim_attr2 A2 on A2.id=F.id and 
                               A2.fromdate=(select MAX(fromdate) from
                                            elim_attr2 where id=F.id);
";
# TODO: same as above but for some given date also? 
# TODO: 


####
####  Connect and start timeing
####

$dbh = $server->connect();
$start_time=new Benchmark;

####
#### Create needed tables
####

goto select_test if ($opt_skip_create);

print "Creating tables\n";
$dbh->do("drop table elim_facts" . $server->{'drop_attr'});
$dbh->do("drop table elim_attr1" . $server->{'drop_attr'});
$dbh->do("drop table elim_attr2" . $server->{'drop_attr'});

# The facts table
do_many($dbh,$server->create("elim_facts",
			     ["id integer"],
			     ["primary key (id)"]));

# Attribute1, non-versioned
do_many($dbh,$server->create("elim_attr1",
			     ["id integer",
                              "attr1 integer"],
			     ["primary key (id)",
                              "key (attr1)"]));

# Attribute2, time-versioned
do_many($dbh,$server->create("elim_attr2",
			     ["id integer",
                              "attr2 integer",
                              "fromdate date"],
			     ["primary key (id, fromdate)",
                              "key (attr2,fromdate)"]));

#NOTE: ignoring: if ($limits->{'views'})
$dbh->do("drop view elim_current_facts");
$dbh->do("create view elim_current_facts as $select_current_full_facts");

if ($opt_lock_tables)
{
  do_query($dbh,"LOCK TABLES elim_current_facts WRITE, elim_facts WRITE, elim_attr1 WRITE, elim_attr2 WRITE");
}

if ($opt_fast && defined($server->{vacuum}))
{
  $server->vacuum(1,\$dbh);
}

####
#### Fill the facts table
####
$n_facts= $opt_loop_count;

if ($opt_fast && $server->{transactions})
{
  $dbh->{AutoCommit} = 0;
}

print "Inserting $n_facts rows into facts table\n";
$loop_time=new Benchmark;

$query="insert into elim_facts values (";
for ($id=0; $id < $n_facts ; $id++)
{
  do_query($dbh,"$query $id)");
}

if ($opt_fast && $server->{transactions})
{
  $dbh->commit;
  $dbh->{AutoCommit} = 1;
}

$end_time=new Benchmark;
print "Time to insert ($n_facts): " .
    timestr(timediff($end_time, $loop_time),"all") . "\n\n";

####
#### Fill attr1 table
####
if ($opt_fast && $server->{transactions})
{
  $dbh->{AutoCommit} = 0;
}

print "Inserting $n_facts rows into attr1 table\n";
$loop_time=new Benchmark;

$query="insert into elim_attr1 values (";
for ($id=0; $id < $n_facts ; $id++)
{
  $attr1= ceil(rand($n_facts));
  do_query($dbh,"$query $id, $attr1)");
}

if ($opt_fast && $server->{transactions})
{
  $dbh->commit;
  $dbh->{AutoCommit} = 1;
}

$end_time=new Benchmark;
print "Time to insert ($n_facts): " .
    timestr(timediff($end_time, $loop_time),"all") . "\n\n";

####
#### Fill attr2 table
####
if ($opt_fast && $server->{transactions})
{
  $dbh->{AutoCommit} = 0;
}

print "Inserting $n_facts rows into attr2 table\n";
$loop_time=new Benchmark;

for ($id=0; $id < $n_facts ; $id++)
{
  # Two values for each $id - current one and obsolete one.
  $attr1= ceil(rand($n_facts));
  $query="insert into elim_attr2 values ($id, $attr1, now())";
  do_query($dbh,$query);
  $query="insert into elim_attr2 values ($id, $attr1, '2009-01-01')";
  do_query($dbh,$query);
}

if ($opt_fast && $server->{transactions})
{
  $dbh->commit;
  $dbh->{AutoCommit} = 1;
}

$end_time=new Benchmark;
print "Time to insert ($n_facts): " .
    timestr(timediff($end_time, $loop_time),"all") . "\n\n";

####
####  Finalize the database population
####

if ($opt_lock_tables)
{
  do_query($dbh,"UNLOCK TABLES");
}

if ($opt_fast && defined($server->{vacuum}))
{
  $server->vacuum(1,\$dbh,"elim_facts");
  $server->vacuum(1,\$dbh,"elim_attr1");
  $server->vacuum(1,\$dbh,"elim_attr2");
}

if ($opt_lock_tables)
{
  do_query($dbh,"LOCK TABLES elim_current_facts READ, elim_facts READ, elim_attr1 READ, elim_attr2 READ");
}

####
#### Do some selects on the table
####

select_test:

#
# The selects will be:
#   - N pk-lookups with all attributes 
#   - pk-attribute-based lookup
#   - latest-attribute value based lookup.


###
### Bare facts select:
###
print "testing bare facts facts table\n";
$loop_time=new Benchmark;
$rows=0;
for ($i=0 ; $i < $opt_medium_loop_count ; $i++)
{
  $val= ceil(rand($n_facts));
  $rows+=fetch_all_rows($dbh,"select * from elim_facts where id=$val");
}
$count=$i;

$end_time=new Benchmark;
print "time for select_bare_facts ($count:$rows): " .
    timestr(timediff($end_time, $loop_time),"all") . "\n";


###
### Full facts select, no elimination:
###
print "testing full facts facts table\n";
$loop_time=new Benchmark;
$rows=0;
for ($i=0 ; $i < $opt_medium_loop_count ; $i++)
{
  $val= rand($n_facts);
  $rows+=fetch_all_rows($dbh,"select * from elim_current_facts where id=$val");
}
$count=$i;

$end_time=new Benchmark;
print "time for select_two_attributes ($count:$rows): " .
    timestr(timediff($end_time, $loop_time),"all") . "\n";

###
### Now with elimination: select only only one fact
###
print "testing selection of one attribute\n";
$loop_time=new Benchmark;
$rows=0;
for ($i=0 ; $i < $opt_medium_loop_count ; $i++)
{
  $val= rand($n_facts);
  $rows+=fetch_all_rows($dbh,"select id, attr1 from elim_current_facts where id=$val");
}
$count=$i;

$end_time=new Benchmark;
print "time for select_one_attribute ($count:$rows): " .
    timestr(timediff($end_time, $loop_time),"all") . "\n";

###
### Now with elimination: select only only one fact
###
print "testing selection of one attribute\n";
$loop_time=new Benchmark;
$rows=0;
for ($i=0 ; $i < $opt_medium_loop_count ; $i++)
{
  $val= rand($n_facts);
  $rows+=fetch_all_rows($dbh,"select id, attr2 from elim_current_facts where id=$val");
}
$count=$i;

$end_time=new Benchmark;
print "time for select_one_attribute ($count:$rows): " .
    timestr(timediff($end_time, $loop_time),"all") . "\n";


;

####
#### End of benchmark
####

if ($opt_lock_tables)
{
  do_query($dbh,"UNLOCK TABLES");
}
if (!$opt_skip_delete)
{
  do_query($dbh,"drop table elim_facts, elim_attr1, elim_attr2" . $server->{'drop_attr'});
}

if ($opt_fast && defined($server->{vacuum}))
{
  $server->vacuum(0,\$dbh);
}

$dbh->disconnect;				# close connection

end_benchmark($start_time);