Updated sql-bench to run with PostgreSQL 14.9

- Updated capabilities for PostgreSQL in server.cfg
- Updated test-ATIS & test-table-elimination to work with PostgreSQL
- Updated test-transaction test to also work with non transactional tables

Other things:
- Added test of tables with many keys in test-insert
- Added 2 new GROUP BY .. ORDER BY test
This commit is contained in:
Monty 2023-09-09 15:14:28 +03:00
parent 69c420be3d
commit e39ed5d76f
8 changed files with 267 additions and 107 deletions

1
.gitignore vendored
View file

@ -186,6 +186,7 @@ sql-bench/innotest1b.pl
sql-bench/innotest2.pl sql-bench/innotest2.pl
sql-bench/innotest2a.pl sql-bench/innotest2a.pl
sql-bench/innotest2b.pl sql-bench/innotest2b.pl
sql-bench/output
sql-bench/run-all-tests.pl sql-bench/run-all-tests.pl
sql-bench/server-cfg.pl sql-bench/server-cfg.pl
sql-bench/test-ATIS.pl sql-bench/test-ATIS.pl

View file

@ -25,7 +25,7 @@
# All options to this script is passed to all test program. # All options to this script is passed to all test program.
# useful options: # useful options:
# --fast --force --lock-tables # --fast --force --lock-tables
# --server ==> mysql (default) / mSQL / Pg (postgres) / Solid # --server ==> mariadb (default) / mysql / Pg (postgres) / Oracle
# --user ==> the user with permission to create / drop / select # --user ==> the user with permission to create / drop / select
# --pass ==> password for the user # --pass ==> password for the user
# --cmp ==> Compare --server with one of the others (mysql/mSQL/Pg/Solid) # --cmp ==> Compare --server with one of the others (mysql/mSQL/Pg/Solid)

View file

@ -37,7 +37,7 @@ sub get_server
{ {
my ($name,$host,$database,$odbc,$machine,$socket,$connect_options)=@_; my ($name,$host,$database,$odbc,$machine,$socket,$connect_options)=@_;
my ($server); my ($server);
if ($name =~ /mysql/i) if ($name =~ /mysql/i || $name =~ /mariadb/i)
{ $server=new db_MySQL($host, $database, $machine, $socket,$connect_options); } { $server=new db_MySQL($host, $database, $machine, $socket,$connect_options); }
elsif ($name =~ /pg/i) elsif ($name =~ /pg/i)
{ $server= new db_Pg($host,$database); } { $server= new db_Pg($host,$database); }
@ -77,7 +77,7 @@ sub get_server
{ $server= new db_interbase($host,$database); } { $server= new db_interbase($host,$database); }
else else
{ {
die "Unknown sql server name used: $name\nUse one of: Access, Adabas, AdabasD, Empress, FrontBase, Oracle, Informix, InterBase, DB2, mSQL, Mimer, MS-SQL, MySQL, Pg, Solid, SAPDB or Sybase.\nIf the connection is done trough ODBC the name must end with _ODBC\n"; die "Unknown sql server name used: $name\nUse one of: Access, Adabas, AdabasD, Empress, FrontBase, Oracle, Informix, InterBase, DB2, mSQL, MariaDB, Mimer, MS-SQL, MySQL, Pg, Solid, SAPDB or Sybase.\nIf the connection is done trough ODBC the name must end with _ODBC\n";
} }
if ($name =~ /_ODBC$/i || defined($odbc) && $odbc) if ($name =~ /_ODBC$/i || defined($odbc) && $odbc)
{ {
@ -98,12 +98,12 @@ sub get_server
sub all_servers sub all_servers
{ {
return ["Access", "Adabas", "DB2", "Empress", "FrontBase", "Oracle", return ["Access", "Adabas", "DB2", "Empress", "FrontBase", "Oracle",
"Informix", "InterBase", "Mimer", "mSQL", "MS-SQL", "MySQL", "Pg","SAPDB", "Informix", "InterBase", "MariaDB", "Mimer", "mSQL", "MS-SQL", "MySQL",
"Solid", "Sybase"]; "Pg","SAPDB", "Solid", "Sybase"];
} }
############################################################################# #############################################################################
# First the configuration for MySQL off course :-) # First the configuration for MariaDB / MySQL off course :-)
############################################################################# #############################################################################
package db_MySQL; package db_MySQL;
@ -165,6 +165,7 @@ sub new
$limits{'max_text_size'} = 1000000; # Good enough for tests $limits{'max_text_size'} = 1000000; # Good enough for tests
$limits{'multi_drop'} = 1; # Drop table can take many tables $limits{'multi_drop'} = 1; # Drop table can take many tables
$limits{'order_by_position'} = 1; # Can use 'ORDER BY 1' $limits{'order_by_position'} = 1; # Can use 'ORDER BY 1'
$limits{'order_by_null'} = 1; # Can use 'ORDER BY NULL'
$limits{'order_by_unused'} = 1; $limits{'order_by_unused'} = 1;
$limits{'query_size'} = 1000000; # Max size with default buffers. $limits{'query_size'} = 1000000; # Max size with default buffers.
$limits{'select_without_from'}= 1; # Can do 'select 1'; $limits{'select_without_from'}= 1; # Can do 'select 1';
@ -224,7 +225,7 @@ sub version
if ($sth->execute && (@row = $sth->fetchrow_array)) if ($sth->execute && (@row = $sth->fetchrow_array))
{ {
$row[0] =~ s/-/ /g; # To get better tables with long names $row[0] =~ s/-/ /g; # To get better tables with long names
$version="MySQL $row[0]"; $version="$row[0]";
} }
$sth->finish; $sth->finish;
@ -283,7 +284,6 @@ sub create
} }
foreach $field (@$fields) foreach $field (@$fields)
{ {
# $field =~ s/ decimal/ double(10,2)/i;
$field =~ s/ big_decimal/ double(10,2)/i; $field =~ s/ big_decimal/ double(10,2)/i;
$query.= $field . ','; $query.= $field . ',';
} }
@ -604,12 +604,14 @@ sub new
$self->{'transactions'} = 1; # Transactions enabled $self->{'transactions'} = 1; # Transactions enabled
$self->{"vacuum"} = 1; $self->{"vacuum"} = 1;
$limits{'join_optimizer'} = 1; # Can optimize FROM tables $limits{'join_optimizer'} = 1; # Can optimize FROM tables
# load_data_infile could use function 'insert_file', but I could not get it to
# work because of permissions problems. Disabling for now.
$limits{'load_data_infile'} = 0; $limits{'load_data_infile'} = 0;
$limits{'NEG'} = 1; $limits{'NEG'} = 1;
$limits{'alter_add_multi_col'}= 0; # alter_add_multi_col ? $limits{'alter_add_multi_col'}= 1;
$limits{'alter_table'} = 1; $limits{'alter_table'} = 1;
$limits{'alter_table_dropcol'}= 0; $limits{'alter_table_dropcol'}= 1;
$limits{'alter_table_after'} = 0; # Have ALTER TABLE .. AFTER other_column
$limits{'column_alias'} = 1; $limits{'column_alias'} = 1;
$limits{'func_extra_%'} = 1; $limits{'func_extra_%'} = 1;
$limits{'func_extra_if'} = 0; $limits{'func_extra_if'} = 0;
@ -649,7 +651,7 @@ sub new
$limits{'working_all_fields'} = 1; $limits{'working_all_fields'} = 1;
$limits{'working_blobs'} = 1; # If big varchar/blobs works $limits{'working_blobs'} = 1; # If big varchar/blobs works
$limits{'multi_distinct'} = 1; # allows select count(distinct a),count(distinct b).. $limits{'multi_distinct'} = 1; # allows select count(distinct a),count(distinct b)..
$limits{'insert_multi_value'} = 1; # Have INSERT ... values (1,2),(3,4)
return $self; return $self;
} }
@ -657,21 +659,20 @@ sub new
sub version sub version
{ {
my ($version,$dir); my ($self)=@_;
$version = "PostgreSQL version ???"; my ($dbh,$sth,$version,@row);
foreach $dir ($ENV{'PGDATA'},"/usr/local/pgsql/data", "/usr/local/pg/data")
$dbh=$self->connect();
$sth = $dbh->prepare("select VERSION()") or die $DBI::errstr;
$version="PostgreSQL ?";
if ($sth->execute && (@row = $sth->fetchrow_array))
{ {
if ($dir && -e "$dir/PG_VERSION") $row[0] =~ s/-/ /g; # To get better tables with long names
{ $version="PostgreSQL $row[0]";
$version= `cat $dir/PG_VERSION`;
if ($? == 0)
{
chomp($version);
$version .= "/ODBC" if ($self->{'data_source'} =~ /:ODBC:/);
return "PostgreSQL $version";
}
}
} }
$sth->finish;
$dbh->disconnect;
$version .= "/ODBC" if ($self->{'data_source'} =~ /:ODBC:/); $version .= "/ODBC" if ($self->{'data_source'} =~ /:ODBC:/);
return $version; return $version;
} }
@ -707,9 +708,6 @@ sub create
$field =~ s/int\(\d*\)/int/; $field =~ s/int\(\d*\)/int/;
$field =~ s/float\(\d*,\d*\)/float/; $field =~ s/float\(\d*,\d*\)/float/;
$field =~ s/ double/ float/; $field =~ s/ double/ float/;
# $field =~ s/ decimal/ float/i;
# $field =~ s/ big_decimal/ float/i;
# $field =~ s/ date/ int/i;
# Pg doesn't have blob, it has text instead # Pg doesn't have blob, it has text instead
$field =~ s/ blob/ text/; $field =~ s/ blob/ text/;
$query.= $field . ','; $query.= $field . ',';
@ -718,13 +716,14 @@ sub create
push(@queries,$query); push(@queries,$query);
foreach $index (@$index) foreach $index (@$index)
{ {
$index =~ s/primary key/unique index primary_key/i; if ($index =~ /primary key/ || $index =~ /PRIMARY KEY/)
if ($index =~ /^unique.*\(([^\(]*)\)$/i)
{ {
# original: $indfield="using btree (" .$1.")"; $query= substr($query, 0, length($query)-1) . ", $index )";
# using btree doesn´t seem to work with Postgres anymore; it creates next;
# the table and adds the index, but it isn´t unique }
$indfield=" (" .$1.")"; elsif ($index =~ /^unique.*\(([^\(]*)\)$/i)
{
$indfield=" (" .$1.")";
$in="unique index"; $in="unique index";
$table="index_$nr"; $nr++; $table="index_$nr"; $nr++;
} }
@ -752,52 +751,14 @@ sub insert_file {
# Syntax: # Syntax:
# copy [binary] <class_name> [with oids] # copy [binary] <class_name> [with oids]
# {to|from} {<filename>|stdin|stdout} [using delimiters <delim>] # {to|from} {<filename>|stdin|stdout} [using delimiters <delim>]
print "The ascii files aren't correct for postgres ....!!!\n"; $command = "copy $dbname from '$file' using delimiters ',' QUOTE ''''";
$command = "copy $dbname from '$file' using delimiters ','";
print "$command\n"; print "$command\n";
$sth = $dbh->do($command) or die $DBI::errstr; $sth = $dbh->do($command) or die $DBI::errstr;
return $sth; return $sth;
} }
#
# As postgreSQL wants A % B instead of standard mod(A,B) we have to map
# This will not handle all cases, but as the benchmarks doesn't use functions
# inside MOD() the following should work
#
# PostgreSQL cant handle count(*) or even count(1), but it can handle
# count(1+1) sometimes. ==> this is solved in PostgreSQL 6.3
#
# PostgreSQL 6.5 is supporting MOD.
sub query { sub query {
my($self,$sql) = @_; my($self,$sql) = @_;
my(@select,$change);
# if you use PostgreSQL 6.x and x is lower as 5 then uncomment the line below.
# $sql =~ s/mod\(([^,]*),([^\)]*)\)/\($1 % $2\)/gi;
#
# if you use PostgreSQL 6.1.x uncomment the lines below
# if ($sql =~ /select\s+count\(\*\)\s+from/i) {
# }
# elsif ($sql =~ /count\(\*\)/i)
# {
# if ($sql =~ /select\s+(.*)\s+from/i)
# {
# @select = split(/,/,$1);
# if ($select[0] =~ /(.*)\s+as\s+\w+$/i)
# {
# $change = $1;
# }
# else
# {
# $change = $select[0];
# }
# }
# if (($change =~ /count/i) || ($change eq "")) {
# $change = "1+1";
# }
# $sql =~ s/count\(\*\)/count($change)/gi;
# }
# till here.
return $sql; return $sql;
} }
@ -849,10 +810,8 @@ sub vacuum
} }
else else
{ {
# $dbh->do("vacuum pg_attributes") || die "Got error: $DBI::errstr when executing 'vacuum'\n"; $dbh->do("vacuum analyze") || die "Got error: $DBI::errstr when executing 'vacuum analyze'\n";
# $dbh->do("vacuum pg_index") || die "Got error: $DBI::errstr when executing 'vacuum'\n"; $dbh->do("vacuum") || die "Got error: $DBI::errstr when executing 'vacuum'\n";
$dbh->do("vacuum analyze") || die "Got error: $DBI::errstr when executing 'vacuum analyze'\n";
$dbh->do("vacuum") || die "Got error: $DBI::errstr when executing 'vacuum'\n";
} }
$end_time=new Benchmark; $end_time=new Benchmark;
print "Time for book-keeping (1): " . print "Time for book-keeping (1): " .

View file

@ -220,7 +220,7 @@ print "Retrieving data\n";
"select category,count(*) from aircraft where engines=2 group by category having count(*)>4",3,$limits->{'group_functions'} && $limits->{'having_with_group'}, "select category,count(*) from aircraft where engines=2 group by category having count(*)>4",3,$limits->{'group_functions'} && $limits->{'having_with_group'},
"select flight_number,range_miles,fare_class FROM aircraft,flight,flight_class WHERE flight.flight_code=flight_class.flight_code AND flight.aircraft_code=aircraft.aircraft_code AND range_miles<>0 AND (stops=1 OR stops=2) GROUP BY flight_number,range_miles,fare_class",150,$limits->{'group_functions'}, "select flight_number,range_miles,fare_class FROM aircraft,flight,flight_class WHERE flight.flight_code=flight_class.flight_code AND flight.aircraft_code=aircraft.aircraft_code AND range_miles<>0 AND (stops=1 OR stops=2) GROUP BY flight_number,range_miles,fare_class",150,$limits->{'group_functions'},
"select distinct from_airport.time_zone_code,to_airport.time_zone_code,(FLOOR(arrival_time/100)*60+MOD(arrival_time,100)-FLOOR(departure_time/100)*60-MOD(departure_time,100)-time_elapsed)/60 AS time_zone_diff FROM flight,airport AS from_airport,airport AS to_airport WHERE flight.from_airport=from_airport.airport_code AND flight.to_airport=to_airport.airport_code GROUP BY from_airport.time_zone_code,to_airport.time_zone_code,arrival_time,departure_time,time_elapsed",21,$limits->{'func_odbc_mod'} && $limits->{'func_odbc_floor'} && $limits->{'group_functions'}, "select distinct from_airport.time_zone_code,to_airport.time_zone_code,(FLOOR(arrival_time/100)*60+MOD(arrival_time,100)-FLOOR(departure_time/100)*60-MOD(departure_time,100)-time_elapsed)/60 AS time_zone_diff FROM flight,airport AS from_airport,airport AS to_airport WHERE flight.from_airport=from_airport.airport_code AND flight.to_airport=to_airport.airport_code GROUP BY from_airport.time_zone_code,to_airport.time_zone_code,arrival_time,departure_time,time_elapsed",21,$limits->{'func_odbc_mod'} && $limits->{'func_odbc_floor'} && $limits->{'group_functions'},
"select DISTINCT from_airport.time_zone_code,to_airport.time_zone_code,MOD((FLOOR(arrival_time/100)*60+MOD(arrival_time,100)-FLOOR(departure_time/100)*60-MOD(departure_time,100)-time_elapsed)/60+36,24)-12 AS time_zone_diff FROM flight,airport AS from_airport,airport AS to_airport WHERE flight.from_airport=from_airport.airport_code AND flight.to_airport=to_airport.airport_code and MOD((FLOOR(arrival_time/100)*60+MOD(arrival_time,100)-FLOOR(departure_time/100)*60-MOD(departure_time,100)-time_elapsed)/60+36,24)-12 < 10",14,$limits->{'func_odbc_mod'} && $limits->{'func_odbc_floor'} && $limits->{'group_functions'}, "select DISTINCT from_airport.time_zone_code,to_airport.time_zone_code,MOD(CAST((FLOOR(arrival_time/100)*60+MOD(arrival_time,100)-FLOOR(departure_time/100)*60-MOD(departure_time,100)-time_elapsed)/60+36 AS INTEGER),24)-12 AS time_zone_diff FROM flight,airport AS from_airport,airport AS to_airport WHERE flight.from_airport=from_airport.airport_code AND flight.to_airport=to_airport.airport_code and MOD(CAST((FLOOR(arrival_time/100)*60+MOD(arrival_time,100)-FLOOR(departure_time/100)*60-MOD(departure_time,100)-time_elapsed)/60+36 AS INTEGER),24)-12 < 10",14,$limits->{'func_odbc_mod'} && $limits->{'func_odbc_floor'} && $limits->{'group_functions'},
"select from_airport,to_airport,range_miles,time_elapsed FROM aircraft,flight WHERE aircraft.aircraft_code=flight.aircraft_code AND to_airport NOT LIKE from_airport AND range_miles<>0 AND time_elapsed<>0 GROUP BY from_airport,to_airport,range_miles,time_elapsed",409,$limits->{'group_functions'} && $limits->{'like_with_column'}, "select from_airport,to_airport,range_miles,time_elapsed FROM aircraft,flight WHERE aircraft.aircraft_code=flight.aircraft_code AND to_airport NOT LIKE from_airport AND range_miles<>0 AND time_elapsed<>0 GROUP BY from_airport,to_airport,range_miles,time_elapsed",409,$limits->{'group_functions'} && $limits->{'like_with_column'},
"SELECT airport.country_name,state.state_name,city.city_name,airport_service.direction FROM airport_service,state,airport,city WHERE airport_service.city_code=city.city_code AND airport_service.airport_code=airport.airport_code AND state.state_code=airport.state_code AND state.state_code=city.state_code AND airport.state_code=city.state_code AND airport.country_name=city.country_name AND airport.country_name=state.country_name AND city.time_zone_code=airport.time_zone_code GROUP BY airport.country_name,state.state_name,city.city_name,airport_service.direction ORDER BY state_name",11,$limits->{'group_functions'}, "SELECT airport.country_name,state.state_name,city.city_name,airport_service.direction FROM airport_service,state,airport,city WHERE airport_service.city_code=city.city_code AND airport_service.airport_code=airport.airport_code AND state.state_code=airport.state_code AND state.state_code=city.state_code AND airport.state_code=city.state_code AND airport.country_name=city.country_name AND airport.country_name=state.country_name AND city.time_zone_code=airport.time_zone_code GROUP BY airport.country_name,state.state_name,city.city_name,airport_service.direction ORDER BY state_name",11,$limits->{'group_functions'},
"SELECT airport.country_name,state.state_name,city.city_name,airport_service.direction FROM airport_service,state,airport,city WHERE airport_service.city_code=city.city_code AND airport_service.airport_code=airport.airport_code AND state.state_code=airport.state_code AND state.state_code=city.state_code AND airport.state_code=city.state_code AND airport.country_name=city.country_name AND airport.country_name=state.country_name AND city.time_zone_code=airport.time_zone_code GROUP BY airport.country_name,state.state_name,city.city_name,airport_service.direction ORDER BY state_name DESC",11,$limits->{'group_functions'}, "SELECT airport.country_name,state.state_name,city.city_name,airport_service.direction FROM airport_service,state,airport,city WHERE airport_service.city_code=city.city_code AND airport_service.airport_code=airport.airport_code AND state.state_code=airport.state_code AND state.state_code=city.state_code AND airport.state_code=city.state_code AND airport.country_name=city.country_name AND airport.country_name=state.country_name AND city.time_zone_code=airport.time_zone_code GROUP BY airport.country_name,state.state_name,city.city_name,airport_service.direction ORDER BY state_name DESC",11,$limits->{'group_functions'},
@ -369,7 +369,7 @@ sub init_data
@class_of_service= @class_of_service=
$server->create("class_of_service", $server->create("class_of_service",
["class_code char(2) NOT NULL", ["class_code char(2) NOT NULL",
"`rank` tinyint(2) NOT NULL", "rank tinyint(2) NOT NULL",
"class_description char(80) NOT NULL"], "class_description char(80) NOT NULL"],
["PRIMARY KEY (class_code)"]); ["PRIMARY KEY (class_code)"]);
@code_description= @code_description=

View file

@ -39,6 +39,7 @@ $small_loop_count=10; # Loop for full table retrieval
$range_loop_count=$small_loop_count*50; $range_loop_count=$small_loop_count*50;
$many_keys_loop_count=$opt_loop_count; $many_keys_loop_count=$opt_loop_count;
$opt_read_key_loop_count=$opt_loop_count; $opt_read_key_loop_count=$opt_loop_count;
$many_key_update=10000;
$pwd = cwd(); $pwd = "." if ($pwd eq ''); $pwd = cwd(); $pwd = "." if ($pwd eq '');
require "$pwd/bench-init.pl" || die "Can't read Configuration file: $!\n"; require "$pwd/bench-init.pl" || die "Can't read Configuration file: $!\n";
@ -49,16 +50,19 @@ if ($opt_small_test)
$many_keys_loop_count=$opt_loop_count/10; $many_keys_loop_count=$opt_loop_count/10;
$range_loop_count=10; $range_loop_count=10;
$opt_read_key_loop_count=10; $opt_read_key_loop_count=10;
$many_key_update=10;
} }
elsif ($opt_small_tables) elsif ($opt_small_tables)
{ {
$opt_loop_count=10000; # number of rows/3 $opt_loop_count=10000; # number of rows/3
$many_keys_loop_count=$opt_loop_count; $many_keys_loop_count=$opt_loop_count;
$opt_read_key_loop_count=10; $opt_read_key_loop_count=10;
$many_key_update=10;
} }
elsif ($opt_small_key_tables) elsif ($opt_small_key_tables)
{ {
$many_keys_loop_count/=10; $many_keys_loop_count/=10;
$many_key_update/=10;
} }
if ($opt_loop_count < 100) if ($opt_loop_count < 100)
@ -101,13 +105,16 @@ $dbh = $server->connect();
#### Create needed tables #### Create needed tables
#### ####
goto keys_test if ($opt_stage == 2);
goto select_test if ($opt_skip_create); goto select_test if ($opt_skip_create);
print "Creating tables\n";
$dbh->do("drop table bench1" . $server->{'drop_attr'}); $dbh->do("drop table bench1" . $server->{'drop_attr'});
$dbh->do("drop table bench2" . $server->{'drop_attr'}); $dbh->do("drop table bench2" . $server->{'drop_attr'});
$dbh->do("drop table bench3" . $server->{'drop_attr'}); $dbh->do("drop table bench3" . $server->{'drop_attr'});
goto keys_test if ($opt_stage == 2);
goto keys_test2 if ($opt_stage == 3);
print "Creating tables\n";
do_many($dbh,$server->create("bench1", do_many($dbh,$server->create("bench1",
["id int NOT NULL", ["id int NOT NULL",
"id2 int NOT NULL", "id2 int NOT NULL",
@ -1590,6 +1597,181 @@ if ($limits->{'insert_multi_value'})
timestr(timediff($end_time, $loop_time),"all") . "\n\n"; timestr(timediff($end_time, $loop_time),"all") . "\n\n";
} }
#
# Test insert and update on a table with a lot of different keys
#
keys_test2:
$keys=min($limits->{'max_index'},8); # 8 is more than enough
print "Insert into table with $many_keys_loop_count rows, $keys keys and with simple primary key\n";
@fields=();
@keys=();
# Make keys on the most important types
@types=(0,0,1,1,0,0,1,1,1,1,1,1,1,1,1,1); # A 1 for each char field
push(@fields,"field1 integer not null");
push(@fields,"field2 integer not null");
push(@fields,"field3 char(16) not null");
push(@fields,"field4 varchar(64) not null");
push(@fields,"field5 float not null");
push(@fields,"field6 double not null");
push(@fields,"field7 integer not null");
for ($i=8 ; $i <= 16 ; $i++)
{
push(@fields,"field$i varchar(16) not null");
}
$query="primary key (field1) ";
push (@keys,$query);
# Create other keys
for ($i=2 ; $i <= $keys ; $i++)
{
push(@keys,"index index$i (field$i)");
}
do_many($dbh,$server->create("bench1",\@fields,\@keys));
if ($opt_lock_tables)
{
$dbh->do("LOCK TABLES bench1 WRITE") || die $DBI::errstr;
}
$loop_time=new Benchmark;
if ($opt_fast && $server->{transactions})
{
$dbh->{AutoCommit} = 0;
}
$fields=$#fields+1;
if (($opt_fast || $opt_fast_insert) && $server->{'limits'}->{'insert_multi_value'})
{
$query_size=$server->{'limits'}->{'query_size'};
$query="insert into bench1 values ";
$res=$query;
for ($i=1; $i <= $many_keys_loop_count; $i++)
{
$id= $i;
$rand=$random[$i];
$tmp="($id,$id,'test$rand','ABCDEF$rand',$rand.0,$rand.0,$rand,";
for ($j=8; $j <= $fields ; $j++)
{
$tmp.= ($types[$j] == 0) ? "$rand," : "'$rand',";
}
substr($tmp,-1)=")";
if (length($tmp)+length($res) < $query_size)
{
$res.= $tmp . ",";
}
else
{
$sth = $dbh->do(substr($res,0,length($res)-1)) or die "$DBI::errstr";
$res=$query . $tmp . ",";
}
}
$sth = $dbh->do(substr($res,0,length($res)-1)) or die $DBI::errstr;
}
else
{
for ($i=1; $i <= $many_keys_loop_count; $i++)
{
$id= $i;
$rand=$random[$i];
$query="insert into bench1 values ($id,$id,'test$rand','ABCDEF$rand',$rand.0,$rand.0,$rand,";
for ($j=8; $j <= $fields ; $j++)
{
$query.= ($types[$j] == 0) ? "$rand," : "'$rand',";
}
substr($query,-1)=")";
print "query1: $query\n" if ($opt_debug);
$dbh->do($query) or die "Got error $DBI::errstr with query: $query\n";
}
}
if ($opt_fast && $server->{transactions})
{
$dbh->commit;
$dbh->{AutoCommit} = 1;
}
$end_time=new Benchmark;
print "Time for insert_many_keys ($many_keys_loop_count): " .
timestr(timediff($end_time, $loop_time),"all") . "\n\n";
if ($opt_fast && defined($server->{vacuum}))
{
if ($opt_lock_tables)
{
do_query($dbh,"UNLOCK TABLES");
}
$server->vacuum(1,\$dbh,"bench1");
if ($opt_lock_tables)
{
$sth = $dbh->do("LOCK TABLES bench1 WRITE") || die $DBI::errstr;
}
}
#
# Testing of update of table with many keys
#
$loop_time=new Benchmark;
for ($i=0 ; $i< $many_key_update; $i++)
{
$tmp= ($i*11 % $many_keys_loop_count)+1;
$query="update bench1 set field7=$i where field1=$tmp";
$dbh->do($query) or die "Got error $DBI::errstr with query $query\n";
}
$end_time=new Benchmark;
print "Time for many_key_update_of_key_with_primary ($many_key_update): " .
timestr(timediff($end_time, $loop_time),"all") . "\n\n";
$loop_time=new Benchmark;
for ($i=0 ; $i< $many_key_update; $i++)
{
$tmp= ($i*11 % $many_keys_loop_count)+1;
$query="update bench1 set field7=$i+1 where field2=$tmp";
$dbh->do($query) or die "Got error $DBI::errstr with query $query\n";
}
$end_time=new Benchmark;
print "Time for many_key_update_of_key_with_secondary ($many_key_update): " .
timestr(timediff($end_time, $loop_time),"all") . "\n\n";
$loop_time=new Benchmark;
for ($i=0 ; $i< $many_key_update; $i++)
{
$tmp= ($i*11 % $many_keys_loop_count)+2;
$query="update bench1 set field8='hello', field9='world' where field1=$tmp";
$dbh->do($query) or die "Got error $DBI::errstr with query $query\n";
}
$end_time=new Benchmark;
print "Time for many_key_update_of_field_with_primary ($many_key_update): " .
timestr(timediff($end_time, $loop_time),"all") . "\n\n";
$loop_time=new Benchmark;
for ($i=0 ; $i< $many_key_update; $i++)
{
$tmp= ($i*11 % $many_keys_loop_count)+3;
$query="update bench1 set field8='world', field9='hello' where field2=$tmp";
$dbh->do($query) or die "Got error $DBI::errstr with query $query\n";
}
$end_time=new Benchmark;
print "Time for many_key_update_of_field_with_secondary ($many_key_update): " .
timestr(timediff($end_time, $loop_time),"all") . "\n\n";
$loop_time=new Benchmark;
$sth = $dbh->do("drop table bench1" . $server->{'drop_attr'}) or die $DBI::errstr;
$end_time=new Benchmark;
print "Time for drop table(1): " .
timestr(timediff($end_time, $loop_time),"all") . "\n\n";
#### ####
#### End of benchmark #### End of benchmark
#### ####

View file

@ -336,6 +336,29 @@ if ($limits->{'group_functions'})
print "Time for count_group ($i:$rows): " . print "Time for count_group ($i:$rows): " .
timestr(timediff($end_time, $loop_time),"all") . "\n"; timestr(timediff($end_time, $loop_time),"all") . "\n";
$loop_time=new Benchmark;
$rows=0;
for ($i=0 ; $i < $opt_medium_loop_count ; $i++)
{
$rows+=fetch_all_rows($dbh,"select grp_no_key,count(*) from bench1 group by grp_no_key order by grp_no_key");
}
$end_time=new Benchmark;
print "Time for count_group_order_group ($i:$rows): " .
timestr(timediff($end_time, $loop_time),"all") . "\n";
if ($limits->{'order_by_null'})
{
$loop_time=new Benchmark;
$rows=0;
for ($i=0 ; $i < $opt_medium_loop_count ; $i++)
{
$rows+=fetch_all_rows($dbh,"select grp_no_key,count(*) from bench1 group by grp_no_key order by null");
}
$end_time=new Benchmark;
print "Time for count_group_order_null ($i:$rows): " .
timestr(timediff($end_time, $loop_time),"all") . "\n";
}
$loop_time=new Benchmark; $loop_time=new Benchmark;
$rows=0; $rows=0;
for ($i=0 ; $i < $opt_medium_loop_count ; $i++) for ($i=0 ; $i < $opt_medium_loop_count ; $i++)
@ -344,7 +367,7 @@ if ($limits->{'group_functions'})
} }
$end_time=new Benchmark; $end_time=new Benchmark;
print "Time for count_group_with_order ($i:$rows): " . print "Time for count_group_with_order ($i:$rows): " .
timestr(timediff($end_time, $loop_time),"all") . "\n"; timestr(timediff($end_time, $loop_time),"all") . "\n\n";
} }
if ($limits->{'group_distinct_functions'}) if ($limits->{'group_distinct_functions'})

View file

@ -34,18 +34,7 @@ $select_current_full_facts="
A2.fromdate=(select MAX(fromdate) from A2.fromdate=(select MAX(fromdate) from
elim_attr2 where id=A2.id); elim_attr2 where id=A2.id);
"; ";
$select_current_full_facts=" # TODO: same as above but for some given date also?
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:
#### ####
@ -62,6 +51,7 @@ $start_time=new Benchmark;
goto select_test if ($opt_skip_create); goto select_test if ($opt_skip_create);
print "Creating tables\n"; print "Creating tables\n";
$dbh->do("drop view elim_current_facts");
$dbh->do("drop table elim_facts" . $server->{'drop_attr'}); $dbh->do("drop table elim_facts" . $server->{'drop_attr'});
$dbh->do("drop table elim_attr1" . $server->{'drop_attr'}); $dbh->do("drop table elim_attr1" . $server->{'drop_attr'});
$dbh->do("drop table elim_attr2" . $server->{'drop_attr'}); $dbh->do("drop table elim_attr2" . $server->{'drop_attr'});
@ -76,7 +66,7 @@ do_many($dbh,$server->create("elim_attr1",
["id integer", ["id integer",
"attr1 integer"], "attr1 integer"],
["primary key (id)", ["primary key (id)",
"key (attr1)"])); "index ix_attr1 (attr1)"]));
# Attribute2, time-versioned # Attribute2, time-versioned
do_many($dbh,$server->create("elim_attr2", do_many($dbh,$server->create("elim_attr2",
@ -84,7 +74,7 @@ do_many($dbh,$server->create("elim_attr2",
"attr2 integer", "attr2 integer",
"fromdate date"], "fromdate date"],
["primary key (id, fromdate)", ["primary key (id, fromdate)",
"key (attr2,fromdate)"])); "index ix_attr2 (attr2,fromdate)"]));
#NOTE: ignoring: if ($limits->{'views'}) #NOTE: ignoring: if ($limits->{'views'})
$dbh->do("drop view elim_current_facts"); $dbh->do("drop view elim_current_facts");
@ -304,8 +294,8 @@ if ($opt_lock_tables)
} }
if (!$opt_skip_delete) if (!$opt_skip_delete)
{ {
do_query($dbh,"drop table elim_facts, elim_attr1, elim_attr2" . $server->{'drop_attr'});
$dbh->do("drop view elim_current_facts"); $dbh->do("drop view elim_current_facts");
do_query($dbh,"drop table elim_facts, elim_attr1, elim_attr2" . $server->{'drop_attr'});
} }
if ($opt_fast && defined($server->{vacuum})) if ($opt_fast && defined($server->{vacuum}))

View file

@ -45,13 +45,6 @@ if ($opt_small_test || $opt_small_tables)
$opt_medium_loop_count/=10; $opt_medium_loop_count/=10;
} }
if (!$server->{transactions} && !$opt_force)
{
print "Test skipped because the database doesn't support transactions\n";
exit(0);
}
#### ####
#### Connect and start timeing #### Connect and start timeing
#### ####
@ -90,7 +83,10 @@ $dbh->{AutoCommit} = 0;
### Test insert perfomance ### Test insert perfomance
### ###
test_insert("bench1","insert_commit",0); if ($server->{transactions})
{
test_insert("bench1","insert_commit",0);
}
test_insert("bench2","insert_autocommit",1); test_insert("bench2","insert_autocommit",1);
sub test_insert sub test_insert
@ -130,6 +126,7 @@ print "Test transactions rollback performance\n" if($opt_debug);
# then doing a rollback on these # then doing a rollback on these
# #
if ($server->{transactions})
{ {
my ($id,$rev_id,$grp,$region,$end,$loop_time,$end_time,$commit_loop,$count); my ($id,$rev_id,$grp,$region,$end,$loop_time,$end_time,$commit_loop,$count);
@ -171,6 +168,7 @@ print "Test transactions rollback performance\n" if($opt_debug);
# then doing a rollback on these # then doing a rollback on these
# #
if ($server->{transactions})
{ {
my ($id,$loop_time,$end_time,$commit_loop,$count); my ($id,$loop_time,$end_time,$commit_loop,$count);
@ -208,6 +206,7 @@ print "Test transactions rollback performance\n" if($opt_debug);
# then doing a rollback on these # then doing a rollback on these
# #
if ($server->{transactions})
{ {
my ($id,$loop_time,$end_time,$commit_loop,$count); my ($id,$loop_time,$end_time,$commit_loop,$count);
@ -241,7 +240,10 @@ print "Test transactions rollback performance\n" if($opt_debug);
### Test update perfomance ### Test update perfomance
### ###
test_update("bench1","update_commit",0); if ($server->{transactions})
{
test_update("bench1","update_commit",0);
}
test_update("bench2","update_autocommit",1); test_update("bench2","update_autocommit",1);
sub test_update sub test_update
@ -267,7 +269,10 @@ sub test_update
### Test delete perfomance ### Test delete perfomance
### ###
test_delete("bench1","delete_commit",0); if ($server->{transactions})
{
test_delete("bench1","delete_commit",0);
}
test_delete("bench2","delete_autocommit",1); test_delete("bench2","delete_autocommit",1);
sub test_delete sub test_delete