summaryrefslogtreecommitdiff
path: root/tests/check_costs.pl
blob: a89f3d07160f6c285f159cb737a75bbe1c41311d (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
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
407
408
409
410
411
412
413
414
415
416
417
418
419
420
421
422
423
424
425
426
427
428
429
430
431
432
433
434
435
436
437
438
439
440
441
442
443
444
445
446
447
448
449
450
451
452
453
454
455
456
457
458
459
460
461
462
463
464
465
466
467
468
469
470
471
472
473
474
475
476
477
478
479
480
481
482
483
484
485
486
487
488
489
490
491
492
493
494
495
496
497
498
499
500
501
502
503
504
505
506
507
508
509
510
511
512
513
514
515
516
517
518
519
520
521
522
523
524
525
526
527
528
529
530
531
532
533
534
535
536
537
538
539
540
541
542
543
544
545
546
547
548
549
550
551
552
553
554
555
556
557
558
559
560
561
562
563
564
565
566
567
568
569
570
571
572
573
574
575
576
577
578
579
580
581
582
583
584
585
586
587
588
589
590
591
592
593
594
595
596
597
598
599
600
601
602
603
604
605
606
607
608
609
610
611
612
613
614
615
616
617
618
619
620
621
622
623
624
625
626
627
628
629
630
631
632
633
634
635
636
637
638
639
640
641
642
643
644
645
646
647
648
649
650
651
652
653
654
655
656
657
658
659
660
661
662
663
664
665
666
667
668
669
670
671
672
673
674
675
676
677
678
679
680
681
682
683
684
685
686
687
688
689
690
691
692
693
694
695
696
697
698
699
700
701
702
703
704
705
706
707
708
709
710
711
712
713
714
715
716
717
718
719
720
721
722
723
724
725
726
727
728
729
730
731
732
733
734
735
736
737
738
739
740
741
742
743
744
745
746
747
748
749
750
751
752
753
754
755
756
757
758
759
760
761
762
763
764
765
766
767
768
769
770
771
772
773
774
775
776
777
778
779
780
781
782
783
784
785
786
787
788
789
790
791
792
793
794
795
796
797
798
799
800
801
802
803
804
805
806
807
808
809
810
811
812
813
814
815
816
817
818
819
820
821
822
823
824
825
826
827
828
829
830
831
832
833
834
835
836
837
838
839
840
841
842
843
844
845
846
847
848
849
850
851
852
853
854
855
856
857
858
859
860
861
862
863
864
865
866
867
868
869
870
871
872
873
874
875
876
877
878
879
880
881
882
883
884
885
886
887
888
889
890
891
892
893
894
895
896
897
898
899
900
901
902
903
904
905
906
907
908
909
910
911
912
913
914
915
916
917
918
919
920
921
922
923
924
925
926
927
928
929
930
931
932
933
934
935
936
937
938
939
940
941
942
943
944
945
946
947
948
949
950
951
952
953
954
955
956
957
958
959
960
961
962
963
964
965
966
967
968
969
970
971
972
973
974
975
976
977
978
979
980
981
982
983
984
985
986
987
988
989
990
991
992
993
994
995
996
997
998
999
1000
1001
1002
1003
1004
1005
1006
1007
1008
1009
1010
1011
1012
1013
1014
1015
1016
1017
1018
1019
1020
1021
1022
1023
#!/usr/bin/env perl

# Copyright (C) 2022 MariaDB Foundation
# Use is subject to license terms
#
# This program is free software; you can redistribute it and/or modify
# it under the terms of the GNU General Public License as published by
# the Free Software Foundation; version 2 of the License.
#
# This program is distributed in the hope that it will be useful,
# but WITHOUT ANY WARRANTY; without even the implied warranty of
# MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE.  See the
# GNU General Public License for more details.
#
# You should have received a copy of the GNU General Public License
# along with this program; if not, write to the Free Software
# Foundation, Inc., 51 Franklin Street, Fifth Floor, Boston, MA  02110-1335  USA

# This is a test that runs queries to meassure if the MariaDB cost calculations
# are reasonable.
#
# The following test are run:
# - Full table scan of a table
# - Range scan of the table
# - Index scan of the table
#
# The output can be used to finetune the optimizer cost variables.
#
# The table in question is a similar to the 'lineitem' table used by DBT3
# it has 16 field and could be regarded as a 'average kind of table'.
# Number of fields and record length places a small role when comparing
# index scan and table scan

##################### Standard benchmark inits ##############################

use DBI;
use Getopt::Long;
use Benchmark ':hireswallclock';

package main;

$opt_rows=1000000;
$opt_test_runs= 2;              # Run each test 2 times and take the average
$opt_verbose="";
$opt_host="";
$opt_db="test";
$opt_user="test";
$opt_password="";
$opt_socket=undef;
$opt_skip_drop= undef;
$opt_skip_create= undef;
$opt_init_query= undef;
$opt_analyze= undef;
$opt_where_check= undef;
$opt_engine=undef;
$opt_comment=undef;
$opt_table_suffix=undef;
$opt_table_name= undef;
$opt_grof= undef;
$opt_all_tests=undef;
$opt_ratios= undef;
$opt_mysql= undef;
$has_force_index=1;

@arguments= @ARGV;

GetOptions("host=s","user=s","password=s", "rows=i","test-runs=i","socket=s",
           "db=s", "table-name=s", "skip-drop","skip-create",
           "init-query=s","engine=s","comment=s",
           "gprof", "one-test=s",
           "mysql", "all-tests", "ratios", "where-check",
           "analyze", "verbose") ||
    die "Aborted";

$Mysql::db_errstr=undef;  # Ignore warnings from these

my ($base_table, $table, $dbh, $where_cost, $real_where_cost, $perf_ratio);

if (!$opt_mysql)
{
    @engines= ("aria","innodb","myisam","heap");
}
else
{
    @engines= ("innodb","myisam","heap");
}

# Special handling for some engines

$no_force= 0;

if (defined($opt_engine))
{
    if (lc($engine) eq "archive")
    {
        $has_force_index= 0;     # Skip tests with force index
    }
}


if (defined($opt_gprof) || defined($opt_one_test))
{
    die "one_test must be defined when --gprof is used"
        if (!defined($opt_one_test));
    die "engine must be defined when --gprof or --one-test is used"
        if (!defined($opt_engine));
    die "function '$opt_one_test' does not exist\n"
        if (!defined(&{$opt_one_test}));
}

# We add engine_name to the table name later

$opt_table_name="check_costs" if (!defined($opt_table_name));
$base_table="$opt_db.$opt_table_name";

####
####  Start timeing and start test
####

$|= 1;				# Autoflush
if ($opt_verbose)
{
    $opt_analyze= 1;
}

####
#### Create the table
####

my %attrib;

$attrib{'PrintError'}=0;

if (defined($opt_socket))
{
    $attrib{'mariadb_socket'}=$opt_socket;
}

$dbh = DBI->connect("DBI:MariaDB:$opt_db:$opt_host",
		    $opt_user, $opt_password,\%attrib) || die $DBI::errstr;

print_mariadb_version();
print "Server options: $opt_comment\n" if (defined($opt_comment));
print "Running tests with $opt_rows rows\n";

print "Program arguments:\n";
for ($i= 0 ; $i <= $#arguments; $i++)
{
    my $arg=$arguments[$i];
    if ($arg =~ / /)
    {
        if ($arg =~ /([^ =]*)=(.*)/)
        {
            print "$1=\"$2\" ";
        }
        else
        {
            print "\"$arg\"" . " ";
        }
    }
    else
    {
        print $arguments[$i] . " ";
    }
}
print "\n\n";

@test_names=
    ("table scan no where", "table scan simple where",
     "table scan where no match", "table scan complex where", "table scan",
     "index scan", "index scan 4 parts", "range scan", "eq_ref_index_join",
     "eq_ref_cluster_join", "eq_ref_join", "eq_ref_btree");
$where_tests=3; # Number of where test to be compared with test[0]

if ($opt_mysql)
{
    create_seq_table();
}


if ($opt_engine || defined($opt_one_test))
{
    test_engine(0, $opt_engine);
}
else
{
    my $i;
    undef($opt_skip_create);
    for ($i= 0 ; $i <= $#engines; $i++)
    {
        test_engine($i, $engines[$i]);

        if ($i > 0 && $opt_ratios)
        {
            print "\n";
            my $j;

            print "Ratios $engines[$i] / $engines[0]\n";
            for ($j= $where_tests+1 ; $j <= $#test_names ; $j++)
            {
                if ($res[$i][$j])
                {
                    my $cmp_cost= $res[0][$j]->{'cost'} - $res[0][$j]->{'where_cost'};
                    my $cmp_time= $res[0][$j]->{'time'};
                    my $cur_cost= $res[$i][$j]->{'cost'} - $res[$i][$j]->{'where_cost'};
                    my $cur_time= $res[$i][$j]->{'time'};

                    printf "%14.14s  cost: %6.4f  time: %6.4f  cost_multiplier: %6.4f\n",
                        $test_names[$j],
                        $cur_cost / $cmp_cost,
                        $cur_time / $cmp_time,
                        ($cmp_cost * ($cur_time / $cmp_time))/$cur_cost;
                }
000000            }
        }
#       if ($i + 1 <= $#engines)
        {
            print "-------------------------\n\n";
        }
    }
    print_totals();
}

$dbh->do("drop table if exists $table") if (!defined($opt_skip_drop));
$dbh->disconnect; $dbh=0;	# Close handler
exit(0);


sub test_engine()
{
    my ($i, $engine)= @_;
    my ($cur_rows);

    setup_engine($engine);
    setup($opt_init_query);
    $table= $base_table . "_$engine";
    if (!defined($opt_skip_create) || !check_if_table_exist($table))
    {
        my $index_type="";

        # We should use btree index with heap to ge range scans
        $index_type= "using btree" if (lc($engine) eq "heap");

        print "Creating table $table of type $engine\n";
        $dbh->do("drop table if exists $table");
        $dbh->do("create table $table (
                 `l_orderkey` int(11) NOT NULL,
                 `l_partkey` int(11) DEFAULT NULL,
                 `l_suppkey` int(11) DEFAULT NULL,
                 `l_linenumber` int(11) NOT NULL,
                 `l_extra` int(11) NOT NULL,
                 `l_quantity` double DEFAULT NULL,
                 `l_extendedprice` double DEFAULT NULL,
                 `l_discount` double DEFAULT NULL,
                 `l_tax` double DEFAULT NULL,
                 `l_returnflag` char(1) DEFAULT NULL,
                 `l_linestatus` char(1) DEFAULT NULL,
                 `l_shipDATE` date DEFAULT NULL,
                 `l_commitDATE` date DEFAULT NULL,
                 `l_receiptDATE` date DEFAULT NULL,
                 `l_shipinstruct` char(25) DEFAULT NULL,
                 `l_shipmode` char(10) DEFAULT NULL,
                 `l_comment` varchar(44) DEFAULT NULL,
                 PRIMARY KEY (`l_orderkey`),
                 UNIQUE (`l_linenumber`),
                 UNIQUE (`l_extra`) $index_type,
                 KEY `l_suppkey` $index_type (l_suppkey, l_partkey),
                 KEY `long_suppkey` $index_type
                     (l_partkey, l_suppkey, l_linenumber, l_extra) )
                 ENGINE= $engine")
            or die "Got error on CREATE TABLE: $DBI::errstr";
    }
    $cur_rows= get_row_count($table);
    if ($cur_rows == 0 || !defined($opt_skip_create))
    {
        $dbh->do("insert into $table select
                 seq, seq/10, seq, seq, seq, seq, seq, mod(seq,10)*10,
                 0, 'a','b',
                 date_add('2000-01-01', interval seq/500 day),
                 date_add('2000-01-10', interval seq/500 day),
                 date_add('2000-01-20', interval seq/500 day),
                 left(md5(seq),25),
                 if(seq & 1,'mail','ship'),
                 repeat('a',mod(seq,40))
                 from seq_1_to_$opt_rows")
            or die "Got error on INSERT: $DBI::errstr";

        $sth= $dbh->do("analyze table $table")
            or die "Got error on 'analyze table: " . $dbh->errstr . "\n";
    }
    else
    {
        $opt_rows= $cur_rows;
        die "Table $table is empty. Please run without --skip-create"
            if ($opt_rows == 0);
        print "Reusing old table $table, which has $opt_rows rows\n";
    }

    if (!$opt_mysql)
    {
        $where_cost=get_variable("optimizer_where_cost");
        if (defined($where_cost))
        {
            # Calculate cost of where once. Must be done after table is created
            $real_where_cost= get_where_cost();
            $perf_ratio= $real_where_cost/$where_cost;
            printf "Performance ratio compared to base computer: %6.4f\n",
                $perf_ratio;
        }
        print "\n";
    }
    else
    {
        $where_cost=0.1;        # mysql 'm_row_evaluate_cost'
    }


    if (defined($opt_one_test))
    {
        if (defined($opt_gprof))
        {
            # Argument is the name of the test function
            test_with_gprof($opt_one_test, 10);
            return;
        }
        $opt_one_test->();
        return;
    }

    if ($opt_where_check)
    {
        $res[$i][0]= table_scan_without_where(0);
        $res[$i][1]= table_scan_with_where(1);
        $res[$i][2]= table_scan_with_where_no_match(2);
        $res[$i][3]= table_scan_with_complex_where(3);
    }
    $res[$i][4]=  table_scan_without_where_analyze(4);
    $res[$i][5]=  index_scan(5);
    $res[$i][6]=  index_scan_4_parts(6)  if ($opt_all_tests);
    $res[$i][7]=  range_scan(7);
    $res[$i][8]=  eq_ref_index_join(8);
    $res[$i][9]=  eq_ref_clustered_join(9);
    $res[$i][10]= eq_ref_join(10);
    $res[$i][11]= eq_ref_join_btree(11);

    if ($opt_where_check)
    {
        printf "Variable optimizer_where_cost:  cur: %6.4f  real: %6.4f  prop: %6.4f\n",
            $where_cost, $real_where_cost, $perf_ratio;
        print "Ratio of WHERE costs compared to scan without a WHERE\n";
        for ($j= 1 ; $j <= $where_tests ; $j++)
        {
            print_where_costs($i,$j,0);
        }
        print "\n";
    }

    print "Cost/time ratio for different scans types\n";
    for ($j= $where_tests+1 ; $j <= $#test_names ; $j++)
    {
        if ($res[$i][$j])
        {
            print_costs($test_names[$j], $res[$i][$j]);
        }
    }
}


sub print_costs($;$)
{
    my ($name, $cur_res)= @_;

    # Cost without where clause
    my $cur_cost= $cur_res->{'cost'} - $cur_res->{'where_cost'};
    my $cur_time= $cur_res->{'time'};

    printf "%-20.20s  cost: %9.4f  time: %9.4f  cost/time:  %8.4f\n",
        $name,
        $cur_cost, $cur_time, $cur_cost/$cur_time;
}

sub print_where_costs()
{
    my ($index, $cmp, $base)= @_;

    my $cmp_time= $res[$index][$cmp]->{'time'};
    my $base_time= $res[$index][$base]->{'time'};

    printf "%-30.30s time: %6.4f\n", $test_names[$cmp], $cmp_time / $base_time;
}


# Used to setup things like optimizer_switch or optimizer_cache_hit_ratio

sub setup()
{
    my ($query)= @_;
    my ($sth,$query);

    $sth= $dbh->do("flush tables") ||
        die "Got error on 'flush tables': " . $dbh->errstr . "\n";
    if (defined($query))
    {
      $sth= $dbh->do("$query") ||
          die "Got error on '$query': " . $dbh->errstr . "\n";
    }

    # Set variables that may interfer with timings
    $query= "set \@\@optimizer_switch='index_condition_pushdown=off'";
    $sth= $dbh->do($query) ||
        die "Got error on '$query': " . $dbh->errstr . "\n";
}


sub setup_engine()
{
    my ($engine)= @_;
    my ($sth,$query);

    if (!$opt_mysql)
    {
        # Set variables that may interfere with timings
        $query= "set global $engine.optimizer_disk_read_ratio=0";
        $sth= $dbh->do($query) ||
            die "Got error on '$query': " . $dbh->errstr . "\n";
    }
}

sub create_seq_table
{
    my $name= "seq_1_to_$opt_rows";
    my $i;
    print "Creating $name\n";
    $dbh->do("drop table if exists $name") ||
        die "Error on drop: " . $dbh->errstr ."\n";
    $dbh->do("create table $name (seq int(11) not null) engine=heap")
        || die "Error on create: " . $dbh->errstr ."\n";
    for ($i= 1 ; $i < $opt_rows ; $i+=10)
    {
        $dbh->do("insert into $name values
                 ($i),($i+1),($i+2),($i+3),($i+4),($i+5),($i+6),($i+7),($i+8),($i+9)") || die "Error on insert";
    }
}



##############################################################################
# Query functions
##############################################################################

# Calculate the cost of the WHERE clause

sub table_scan_without_where()
{
    my ($query_id)= @_;
    return run_query($test_names[$query_id],
                     "table_scan", "ALL", $opt_rows,
"select sum(l_quantity) from $table");
}

sub table_scan_with_where()
{
    my ($query_id)= @_;
    return run_query($test_names[$query_id],
                     "table_scan", "ALL", $opt_rows,
"select sum(l_quantity) from $table where l_commitDate >= '2000-01-01' and l_tax >= 0.0");
}

sub table_scan_with_where_no_match()
{
    my ($query_id)= @_;
    return run_query($test_names[$query_id],
                     "table_scan", "ALL", $opt_rows,
"select sum(l_quantity) from $table where l_commitDate >= '2000-01-01' and l_tax > 0.0 /* NO MATCH */");
}


sub table_scan_with_complex_where()
{
    my ($query_id)= @_;
    return run_query($test_names[$query_id],
                     "table_scan", "ALL", $opt_rows,
"select sum(l_quantity) from $table where l_commitDate >= '2000-01-01' and l_quantity*l_extendedprice-l_discount+l_tax > 0.0");
}

# Calculate the time spent for table accesses (done with analyze statment)

# Table scan

sub table_scan_without_where_analyze()
{
    my ($query_id)= @_;
    return run_query_with_analyze($test_names[$query_id],
                                  "table_scan", "ALL", $opt_rows,
"select sum(l_quantity) from $table");
}

# Index scan with 2 key parts

sub index_scan()
{
    my ($query_id)= @_;
    return 0 if (!$has_force_index);
    my ($query_id)= @_;
    return run_query_with_analyze($test_names[$query_id],
                                  "index_scan", "index", $opt_rows,
"select count(*) from $table force index (l_suppkey) where l_suppkey >= 0 and l_partkey >=0");
}

# Index scan with 2 key parts
# This is to check how the number of key parts affects the timeings

sub index_scan_4_parts()
{
    my ($query_id)= @_;
    return 0 if (!$has_force_index);
    return run_query_with_analyze($test_names[$query_id],
                                  "index_scan_4_parts", "index", $opt_rows,
"select count(*) from $table force index (long_suppkey) where l_linenumber >= 0 and l_extra >0");
}

sub range_scan()
{
    my ($query_id)= @_;
    return 0 if (!$has_force_index);
    return run_query_with_analyze($test_names[$query_id],
                                  "range_scan", "range", $opt_rows,
"select sum(l_orderkey) from $table force index(l_suppkey) where l_suppkey >= 0 and l_partkey >=0 and l_discount>=0.0");
}

sub eq_ref_index_join()
{
    my ($query_id)= @_;
    return run_query_with_analyze($test_names[$query_id],
                                  "eq_ref_index_join", "eq_ref", 1,
"select straight_join count(*) from seq_1_to_$opt_rows,$table where seq=l_linenumber");
}

sub eq_ref_clustered_join()
{
    my ($query_id)= @_;
    return run_query_with_analyze($test_names[$query_id],
                                  "eq_ref_cluster_join", "eq_ref", 1,
"select straight_join count(*) from seq_1_to_$opt_rows,$table where seq=l_orderkey");
}

sub eq_ref_join()
{
    my ($query_id)= @_;
    return run_query_with_analyze($test_names[$query_id],
                                  "eq_ref_join", "eq_ref", 1,
"select straight_join count(*) from seq_1_to_$opt_rows,$table where seq=l_linenumber and l_partkey >= 0");
}

sub eq_ref_join_btree()
{
    my ($query_id)= @_;
    return run_query_with_analyze($test_names[$query_id],
                                  "eq_ref_btree", "eq_ref", 1,
"select straight_join count(*) from seq_1_to_$opt_rows,$table where seq=l_extra and l_partkey >= 0");
}


# Calculate the cost of a basic where clause
# This can be used to find out the speed of the current computer compared
# to the reference computer on which the costs where calibrated.

sub get_where_cost()
{
    my ($loop);
    $loop=10000000;
    # Return time in microseconds for one where (= optimizer_where_cost)
    return query_time("select benchmark($loop, l_commitDate >= '2000-01-01' and l_tax >= 0.0) from $table limit 1")/$loop;
}


# Run a query to be able to calculate the costs of filter

sub cost_of_filtering()
{
    my ($query, $cost1, $cost2);
    do_query("set \@\@max_rowid_filter_size=10000000," .
              "optimizer_switch='rowid_filter=on',".
              "\@\@optimizer_scan_setup_cost=1000000");
    do_query("set \@old_cost=\@\@aria.OPTIMIZER_ROW_LOOKUP_COST");
    do_query("set global aria.OPTIMIZER_ROW_LOOKUP_COST=1");
    do_query("flush tables");
    $cost1= run_query_with_analyze("range", "range", "range", 500000,
                           "select count(l_discount) from check_costs_aria as t1 where t1.l_orderkey between 1 and 500000");
    $cost2= run_query_with_analyze("range-all", "range-all", "range|filter", 500000,
                           "select count(l_discount) from check_costs_aria as t1 where t1.l_orderkey between 1 and 500000 and l_linenumber between 1 and 500000");
    $cost3= run_query_with_analyze("range-none","range-none", "range|filter", 500000,
                           "select count(l_discount) from check_costs_aria as t1 where t1.l_orderkey between 1 and 500000 and l_linenumber between 500000 and 1000000");
    do_query("set global aria.OPTIMIZER_ROW_LOOKUP_COST=\@old_cost");
    do_query("flush tables");
    print_costs("range", $cost1);
    print_costs("filter-all",  $cost2);
    print_costs("filter-none", $cost3);
}

sub gprof_cost_of_filtering()
{
    $cost2= run_query_with_analyze("gprof","range-all", "range|filter", 500000,
                           "select count(l_discount) from check_costs_aria as t1 where t1.l_orderkey between 1 and 500000 and l_linenumber between 1 and 500000");
}


###############################################################################
# Help functions for running the queries
###############################################################################


# Run query and return time for query in microseconds

sub query_time()
{
    my ($query)= @_;
    my ($start_time,$end_time,$time,$ms,$sth,$row);

    $start_time= new Benchmark;
    $sth= $dbh->prepare($query) || die "Got error on '$query': " . $dbh->errstr . "\n";
    $sth->execute || die "Got error on '$query': " . $dbh->errstr . "\n";
    $end_time=new Benchmark;
    $row= $sth->fetchrow_arrayref();
    $sth=0;

    $time= timestr(timediff($end_time, $start_time),"nop");
    $time =~ /([\d.]*)/;
    return $1*1000000.0;
}

#
# Run a query and compare the clock time
#

sub run_query()
{
    my ($full_name, $name, $type, $expected_rows, $query)= @_;
    my ($start_time,$end_time,$sth,@row,%res,$i,$optimizer_rows);
    my ($extra, $last_type, $adjust_cost, $ms);
    $adjust_cost=1.0;

    print "Timing full query: $full_name\n$query\n";

    $sth= $dbh->prepare("explain $query") || die "Got error on 'explain $query': " . $dbh->errstr . "\n";
    $sth->execute || die "Got error on 'explain $query': " . $dbh->errstr . "\n";

    print "explain:\n";
    while ($row= $sth->fetchrow_arrayref())
    {
        print $row->[0];
        for ($i= 1 ; $i < @$row; $i++)
        {
            print "  " .  $row->[$i] if (defined($row->[$i]));
        }
        print "\n";

        $extra= $row->[@$row-1];
        $last_type= $row->[3];
        $optimizer_rows= $row->[8];
    }
    if ($last_type ne $type &&
        ($type ne "index" || !($extra =~ /Using index/)))
    {
        print "Warning: Wrong scan type: '$last_type', expected '$type'\n";
    }

    if ($expected_rows >= 0 &&
        (abs($optimizer_rows - $expected_rows)/$expected_rows) > 0.1)
    {
        printf "Warning: Expected $expected_rows instead of $optimizer_rows from EXPLAIN. Adjusting costs\n";
        $adjust_cost= $expected_rows / $optimizer_rows;
    }

    # Do one query to fill the cache
    $sth= $dbh->prepare($query) || die "Got error on '$query': " . $dbh->errstr . "\n";
    $sth->execute || die "Got error on '$query': " . $dbh->errstr . "\n";
    $end_time=new Benchmark;
    $row= $sth->fetchrow_arrayref();
    $sth=0;

    # Run query for real
    $start_time= new Benchmark;
    $sth= $dbh->prepare($query) || die "Got error on '$query': " . $dbh->errstr . "\n";
    $sth->execute || die "Got error on '$query': " . $dbh->errstr . "\n";
    $end_time=new Benchmark;
    $row= $sth->fetchrow_arrayref();
    $sth=0;

    $time= timestr(timediff($end_time, $start_time),"nop");
    $time =~ /([\d.]*)/;
    $ms= $1*1000.0;

    $query= "show status like 'last_query_cost'";
    $sth= $dbh->prepare($query) || die "Got error on '$query': " . $dbh->errstr . "\n";
    $sth->execute || die "Got error on '$query': " . $dbh->errstr . "\n";;
    $row= $sth->fetchrow_arrayref();
    $sth=0;
    $cost= $row->[1] * $adjust_cost;
    printf "%10s  time: %10.10s ms  cost: %6.4f", $name, $ms, $cost;
    if ($adjust_cost != 1.0)
    {
        printf " (was %6.4f)", $row->[1];
    }
    print "\n\n";

    $res{'cost'}= $cost;
    $res{'time'}= $ms;
    return \%res;
}

#
# Run a query and compare the table access time from analyze statement
# The cost works for queries with one or two tables!
#

sub run_query_with_analyze()
{
    my ($full_name,$name, $type, $expected_rows, $query)= @_;
    my ($start_time,$end_time,$sth,@row,%res,$i,$j);
    my ($optimizer_rows, $optimizer_rows_first);
    my ($adjust_cost, $ms, $second_ms, $analyze, $local_where_cost);
    my ($extra, $last_type, $tot_ms, $found_two_tables);

    $found_two_tables= 0;
    $adjust_cost=1.0;
    if (!$opt_mysql)
    {
        $local_where_cost= $where_cost/1000 * $opt_rows;
    }
    else
    {
        $local_where_cost= $where_cost * $opt_rows;
    }
    $optimizer_rows_first= undef;

    print "Timing table access for query: $full_name\n$query\n";

    $sth= $dbh->prepare("explain $query") || die "Got error on 'explain $query': " . $dbh->errstr . "\n";
    $sth->execute || die "Got error on 'explain $query': " . $dbh->errstr . "\n";

    print "explain:\n";
    if (!$opt_mysql)
    {
        $type_pos= 3;
        $row_pos= 8;
    }
    else
    {
        $type_pos= 4;
        $row_pos= 9;
    }

    $j= 0;
    while ($row= $sth->fetchrow_arrayref())
    {
        $j++;
        print $row->[0];
        for ($i= 1 ; $i < @$row; $i++)
        {
            print "  " .  $row->[$i] if (defined($row->[$i]));
            # print "  X" if (!defined($row->[$i]));
        }
        print "\n";

        $extra= $row->[@$row-1];
        $last_type= $row->[$type_pos];
        if (!defined($optimizer_rows_first))
        {
            $optimizer_rows_first= $row->[$row_pos];
        }
        $optimizer_rows= $row->[$row_pos];
    }
    $found_two_tables= 1 if ($j > 1);

    if ($last_type ne $type &&
        ($type ne "index" || !($extra =~ /Using index/)))
    {
        print "Warning: Wrong scan type: '$last_type', expected '$type'\n";
    }
    if ($expected_rows >= 0 &&
        (abs($optimizer_rows - $expected_rows)/$expected_rows) > 0.1)
    {
        printf "Warning: Expected $expected_rows instead of $optimizer_rows from EXPLAIN. Adjusting costs\n";
        $adjust_cost= $expected_rows / $optimizer_rows;
    }

    # Do one query to fill the cache
    if (!defined($opt_grof))
    {
        $sth= $dbh->prepare($query) || die "Got error on '$query': " . $dbh->errstr . "\n";
        $sth->execute || die "Got error on '$query': " . $dbh->errstr . "\n";
        $row= $sth->fetchrow_arrayref();
        $sth=0;
    }

    # Run the query through analyze statement
    $tot_ms=0;
    if (!$opt_mysql)
    {
    for ($i=0 ; $i < $opt_test_runs ; $i++)
    {
        my ($j);
        $sth= $dbh->prepare("analyze format=json $query" ) || die "Got error on 'analzye $query': " . $dbh->errstr . "\n";
        $sth->execute || die "Got error on '$query': " . $dbh->errstr . "\n";
        $row= $sth->fetchrow_arrayref();
        $analyze= $row->[0];
        $sth=0;

        # Fetch the timings
        $j=0;
        while ($analyze =~ /r_table_time_ms": ([0-9.]*)/g)
        {
            $tot_ms= $tot_ms+ $1;
            $j++;
        }
        if ($j > 2)
        {
            die "Found too many tables, program needs to be extended!"
        }
        # Add cost of filtering
        while ($analyze =~ /r_filling_time_ms": ([0-9.]*)/g)
        {
            $tot_ms= $tot_ms+ $1;
        }
    }
    }
    else
    {
        my $local_table= substr($table,index($table,".")+1);
        for ($i=0 ; $i < $opt_test_runs ; $i++)
        {
            my ($j);
            $sth= $dbh->prepare("explain analyze $query" ) || die "Got error on 'analzye $query': " . $dbh->errstr . "\n";
            $sth->execute || die "Got error on '$query': " . $dbh->errstr . "\n";
            $row= $sth->fetchrow_arrayref();
            $analyze= $row->[0];
            $sth=0;
        }
        # Fetch the timings
        $j=0;

        if ($analyze =~ / $local_table .*actual time=([0-9.]*) .*loops=([0-9]*)/g)
        {
            my $times= $1;
            my $loops= $2;
            $times =~ /\.\.([0-9.]*)/;
            $times= $1;
            $times="0.005" if ($times == 0);
            #print "time: $times  \$1: $1  loops: $loops\n";
            $tot_ms= $tot_ms+ $times*$loops;
            $j++;
        }
        if ($j > 1)
        {
            die "Found too many tables, program needs to be extended!"
        }
    }


    if ($found_two_tables)
    {
        # Add the cost of the where for the two tables. The last table
        # is assumed to have $expected_rows while the first (driving table)
        # may have less rows. Take that into account when calculalting the
        # total where cost.
        $local_where_cost= ($local_where_cost +
                            $local_where_cost *
                            ($optimizer_rows_first/$opt_rows));
    }
    $ms= $tot_ms/$opt_test_runs;

    if ($opt_analyze)
    {
        print "\nanalyze:\n" . $analyze . "\n\n";
    }

    if (!defined($opt_grof))
    {
        # Get last query cost
        $query= "show status like 'last_query_cost'";
        $sth= $dbh->prepare($query) || die "Got error on '$query': " . $dbh->errstr . "\n";
        $sth->execute || die "Got error on '$query': " . $dbh->errstr . "\n";;
        $row= $sth->fetchrow_arrayref();
        $sth=0;
        $cost= $row->[1] * $adjust_cost;

        printf "%10s  time: %10.10s ms  cost-where: %6.4f   cost: %6.4f",
            $name, $ms, $cost - $local_where_cost, $cost;
        if ($adjust_cost != 1.0)
        {
            printf " (cost was %6.4f)", $row->[1];
        }
    }
    else
    {
        printf "%10s  time: %10.10s ms", $name, $ms;
        $cost= 0; $local_where_cost= 0;
    }
    print "\n\n";

    $res{'cost'}= $cost;
    $res{'where_cost'}= $local_where_cost;
    $res{'time'}= $ms;
    return \%res;
}


sub do_query()
{
    my ($query)= @_;
    $dbh->do($query) || die "Got error on '$query': " . $dbh->errstr . "\n";
}


sub print_totals()
{
    my ($i, $j);
    print "Totals per test\n";
    for ($j= $where_tests+1 ; $j <= $#test_names; $j++)
    {
        print "$test_names[$j]:\n";
        for ($i= $0 ; $i <= $#engines ; $i++)
        {
            if ($res[$i][$j])
            {
                my $cost= $res[$i][$j]->{'cost'} - $res[$i][$j]->{'where_cost'};
                my $ms= $res[$i][$j]->{'time'};
                printf "%-8s  %10.4f ms  cost: %10.4f  cost/time: %8.4f\n",
                    $engines[$i], $ms, $cost, $cost/$ms;
            }
        }
    }
}


# This function can be used to test things with gprof

sub test_with_gprof()
{
    my ($function_ref, $loops)= @_;
    my ($sum, $i, $cost);

    printf "Running test $function_ref $loops time\n";
    $sum= 0; $loops=10;
    for ($i=0 ; $i < $loops ; $i++)
    {
        $cost= $function_ref->();
        $sum+= $cost->{'time'};
    }
    print "Average: " . ($sum/$loops) . "\n";
    print "Shuting down server\n";
    $dbh->do("shutdown") || die "Got error ..";
}

##############################################################################
# Get various simple data from MariaDB
##############################################################################

sub print_mariadb_version()
{
    my ($query, $sth, $row);
    $query= "select VERSION()";
    $sth= $dbh->prepare($query) || die "Got error on '$query': " . $dbh->errstr . "\n";
$sth->execute || die "Got error on '$query': " . $dbh->errstr . "\n";;
    $row= $sth->fetchrow_arrayref();
    print "Server: $row->[0]";

    $query= "show variables like 'VERSION_SOURCE_REVISION'";
    $sth= $dbh->prepare($query) || die "Got error on '$query': " . $dbh->errstr . "\n";
$sth->execute || die "Got error on '$query': " . $dbh->errstr . "\n";;
    $row= $sth->fetchrow_arrayref();
    print "  Commit: $row->[1]\n";
}


sub get_row_count()
{
    my ($table)= @_;
    my ($query, $sth, $row);
    $query= "select count(*) from $table";
    $sth= $dbh->prepare($query) || die "Got error on '$query': " . $dbh->errstr . "\n";
    if (!$sth->execute)
    {
        if (!($dbh->errstr =~ /doesn.*exist/))
        {
            die "Got error on '$query': " . $dbh->errstr . "\n";
        }
        return 0;
    }
    $row= $sth->fetchrow_arrayref();
    return $row->[0];
}


sub get_variable()
{
    my ($name)= @_;
    my ($query, $sth, $row);
    $query= "select @@" . $name;
    if (!($sth= $dbh->prepare($query)))
    {
        die "Got error on '$query': " . $dbh->errstr . "\n";
    }
    $sth->execute || die "Got error on '$query': " . $dbh->errstr . "\n";;
    $row= $sth->fetchrow_arrayref();
    return $row->[0];
}


sub check_if_table_exist()
{
    my ($name)= @_;
    my ($query,$sth);
    $query= "select 1 from $name limit 1";
    $sth= $dbh->prepare($query) || die "Got error on '$query': " . $dbh->errstr . "\n";
    print $sth->fetchrow_arrayref();
    if (!$sth->execute || !defined($sth->fetchrow_arrayref()))
    {
        return 0;               # Table does not exists
    }
    return 1;
}