[Rt-commit] rt branch, 4.2/upgrading-indexes-and-review, created. rt-4.1.8-14-g4ecc53b
Ruslan Zakirov
ruz at bestpractical.com
Mon May 6 11:51:31 EDT 2013
The branch, 4.2/upgrading-indexes-and-review has been created
at 4ecc53b1df3b686893a3b2518e154a55cb95fcde (commit)
- Log -----------------------------------------------------------------
commit 734b2ffeacd4e8facca9d0c1ce40123ea3de699b
Author: Ruslan Zakirov <ruz at bestpractical.com>
Date: Wed Apr 10 16:31:06 2013 +0400
a few functions to explore DB indexes
diff --git a/lib/RT/Handle.pm b/lib/RT/Handle.pm
index ad33dd0..9a896fa 100644
--- a/lib/RT/Handle.pm
+++ b/lib/RT/Handle.pm
@@ -1216,6 +1216,275 @@ sub FillIn {
return $sql;
}
+sub Indexes {
+ my $self = shift;
+
+ my %res;
+
+ my $db_type = RT->Config->Get('DatabaseType');
+ my $dbh = $self->dbh;
+
+ my $list;
+ if ( $db_type eq 'mysql' ) {
+ $list = $dbh->selectall_arrayref(
+ 'select distinct table_name, index_name from information_schema.statistics where table_schema = ?',
+ undef, scalar RT->Config->Get('DatabaseName')
+ );
+ }
+ elsif ( $db_type eq 'Pg' ) {
+ $list = $dbh->selectall_arrayref(
+ 'select tablename, indexname from pg_indexes where schemaname = ?',
+ undef, 'public'
+ );
+ }
+ elsif ( $db_type eq 'SQLite' ) {
+ $list = $dbh->selectall_arrayref(
+ 'select tbl_name, name from sqlite_master where type = ?',
+ undef, 'index'
+ );
+ }
+ elsif ( $db_type eq 'Oracle' ) {
+ $list = $dbh->selectall_arrayref(
+ 'select table_name, index_name from dba_indexes where index_name NOT LIKE ? AND lower(Owner) = ?',
+ undef, 'SYS_%$$', lc RT->Config->Get('DatabaseUser'),
+ );
+ }
+ else {
+ die "Not implemented";
+ }
+ push @{ $res{ lc $_->[0] } ||= [] }, lc $_->[1] foreach @$list;
+ return %res;
+}
+
+sub IndexesThatBeginWith {
+ my $self = shift;
+ my %args = (Table => undef, Columns => [], @_);
+
+ my %indexes = $self->Indexes;
+
+ my @check = @{ $args{'Columns'} };
+
+ my @list;
+ foreach my $index ( @{ $indexes{ lc $args{'Table'} } || [] } ) {
+ my %info = $self->IndexInfo( Table => $args{'Table'}, Name => $index );
+ next if @{ $info{'Columns'} } < @check;
+ my $check = join ',', @check;
+ next if join( ',', @{ $info{'Columns'} } ) !~ /^\Q$check\E(?:,|$)/i;
+
+ push @list, \%info;
+ }
+ return sort { @{ $a->{'Columns'} } <=> @{ $b->{'Columns'} } } @list;
+}
+
+sub IndexInfo {
+ my $self = shift;
+ my %args = (Table => undef, Name => undef, @_);
+
+ my $db_type = RT->Config->Get('DatabaseType');
+ my $dbh = $self->dbh;
+
+ my %res = (
+ Table => lc $args{'Table'},
+ Name => lc $args{'Name'},
+ );
+ if ( $db_type eq 'mysql' ) {
+ my $list = $dbh->selectall_arrayref(
+ 'select NON_UNIQUE, COLUMN_NAME, SUB_PART
+ from information_schema.statistics
+ where table_schema = ? AND table_name = ? AND index_name = ?
+ ORDER BY SEQ_IN_INDEX',
+ undef, scalar RT->Config->Get('DatabaseName'), $args{'Table'}, $args{'Name'},
+ );
+ return () unless $list && @$list;
+ $res{'Unique'} = $list->[0][0]? 0 : 1;
+ $res{'Functional'} = 0;
+ $res{'Columns'} = [ map $_->[1], @$list ];
+ }
+ elsif ( $db_type eq 'Pg' ) {
+ my $index = $dbh->selectrow_hashref(
+ 'select ix.*, pg_get_expr(ix.indexprs, ix.indrelid) as functions
+ from
+ pg_class t, pg_class i, pg_index ix
+ where
+ t.relname ilike ?
+ and t.relkind = ?
+ and i.relname ilike ?
+ and ix.indrelid = t.oid
+ and ix.indexrelid = i.oid
+ ',
+ undef, $args{'Table'}, 'r', $args{'Name'},
+ );
+ return () unless $index && keys %$index;
+ $res{'Unique'} = $index->{'indisunique'};
+ $res{'Functional'} = (grep $_ == 0, split ' ', $index->{'indkey'})? 1 : 0;
+ $res{'Columns'} = [ map int($_), split ' ', $index->{'indkey'} ];
+ my $columns = $dbh->selectall_hashref(
+ 'select a.attnum, a.attname
+ from pg_attribute a where a.attrelid = ?',
+ 'attnum', undef, $index->{'indrelid'}
+ );
+ if ($index->{'functions'}) {
+ # XXX: this is good enough for us
+ $index->{'functions'} = [ split /,\s+/, $index->{'functions'} ];
+ }
+ foreach my $e ( @{ $res{'Columns'} } ) {
+ if (exists $columns->{$e} ) {
+ $e = $columns->{$e}{'attname'};
+ }
+ elsif ( !$e ) {
+ $e = shift @{ $index->{'functions'} };
+ }
+ }
+
+ foreach my $column ( @{$res{'Columns'}} ) {
+ next unless $column =~ s/^lower\( \s* \(? (\w+) \)? (?:::text)? \s* \)$/$1/ix;
+ $res{'CaseInsensitive'}{ lc $1 } = 1;
+ }
+ }
+ elsif ( $db_type eq 'SQLite' ) {
+ my $list = $dbh->selectall_arrayref("pragma index_info('$args{'Name'}')");
+ return () unless $list && @$list;
+
+ $res{'Functional'} = 0;
+ $res{'Columns'} = [ map $_->[2], @$list ];
+
+ $list = $dbh->selectall_arrayref("pragma index_list('$args{'Table'}')");
+ $res{'Unique'} = (grep lc $_->[1] eq lc $args{'Name'}, @$list)[0][2]? 1 : 0;
+ }
+ elsif ( $db_type eq 'Oracle' ) {
+ my $index = $dbh->selectrow_hashref(
+ 'select uniqueness, funcidx_status from dba_indexes
+ where lower(table_name) = ? AND lower(index_name) = ? AND LOWER(Owner) = ?',
+ undef, lc $args{'Table'}, lc $args{'Name'}, lc RT->Config->Get('DatabaseUser'),
+ );
+ return () unless $index && keys %$index;
+ $res{'Unique'} = $index->{'uniqueness'} eq 'UNIQUE'? 1 : 0;
+ $res{'Functional'} = $index->{'funcidx_status'}? 1 : 0;
+
+ my %columns = map @$_, @{ $dbh->selectall_arrayref(
+ 'select column_position, column_name from dba_ind_columns
+ where lower(table_name) = ? AND lower(index_name) = ? AND LOWER(index_owner) = ?',
+ undef, lc $args{'Table'}, lc $args{'Name'}, lc RT->Config->Get('DatabaseUser'),
+ ) };
+ $columns{ $_->[0] } = $_->[1] foreach @{ $dbh->selectall_arrayref(
+ 'select column_position, column_expression from dba_ind_expressions
+ where lower(table_name) = ? AND lower(index_name) = ? AND LOWER(index_owner) = ?',
+ undef, lc $args{'Table'}, lc $args{'Name'}, lc RT->Config->Get('DatabaseUser'),
+ ) };
+ $res{'Columns'} = [ map $columns{$_}, sort { $a <=> $b } keys %columns ];
+
+ foreach my $column ( @{$res{'Columns'}} ) {
+ next unless $column =~ s/^lower\( \s* " (\w+) " \s* \)$/$1/ix;
+ $res{'CaseInsensitive'}{ lc $1 } = 1;
+ }
+ }
+ else {
+ die "Not implemented";
+ }
+ $_ = lc $_ foreach @{ $res{'Columns'} };
+ return %res;
+}
+
+sub DropIndex {
+ my $self = shift;
+ my %args = (Table => undef, Name => undef, @_);
+
+ my $db_type = RT->Config->Get('DatabaseType');
+ my $dbh = $self->dbh;
+ local $dbh->{'PrintError'} = 0;
+ local $dbh->{'RaiseError'} = 0;
+
+ my $res;
+ if ( $db_type eq 'mysql' ) {
+ $res = $dbh->do(
+ 'drop index '. $dbh->quote_identifier($args{'Name'}) ." on $args{'Table'}",
+ );
+ }
+ elsif ( $db_type eq 'Pg' ) {
+ $res = $dbh->do("drop index $args{'Name'} CASCADE");
+ }
+ elsif ( $db_type eq 'SQLite' ) {
+ $res = $dbh->do("drop index $args{'Name'}");
+ }
+ elsif ( $db_type eq 'Oracle' ) {
+ my $user = RT->Config->Get('DatabaseUser');
+ $res = $dbh->do("drop index $user.$args{'Name'}");
+ }
+ else {
+ die "Not implemented";
+ }
+ my $desc = $self->IndexDescription( %args );
+ return ($res, $res? "Dropped $desc" : "Couldn't drop $desc: ". $dbh->errstr);
+}
+
+sub DropIndexIfExists {
+ my $self = shift;
+ my %args = (Table => undef, Name => undef, @_);
+
+ my %indexes = $self->Indexes;
+ return (1, ucfirst($self->IndexDescription( %args )) ." doesn't exists")
+ unless grep $_ eq lc $args{'Name'},
+ @{ $indexes{ lc $args{'Table'} } || []};
+ return $self->DropIndex(%args);
+}
+
+sub CreateIndex {
+ my $self = shift;
+ my %args = ( Table => undef, Name => undef, Columns => [], CaseInsensitive => {}, @_ );
+
+ my $name = $args{'Name'};
+ unless ( $name ) {
+ my %indexes = $self->Indexes;
+ %indexes = map { $_ => 1 } @{ $indexes{ lc $args{'Table'} } || [] };
+ my $i = 1;
+ $i++ while $indexes{ lc($args{'Table'}).$i };
+ $name = lc($args{'Table'}).$i;
+ }
+
+ my @columns = @{ $args{'Columns'} };
+ if ( $self->CaseSensitive ) {
+ foreach my $column ( @columns ) {
+ next unless $args{'CaseInsensitive'}{ lc $column };
+ $column = "LOWER($column)";
+ }
+ }
+
+ my $sql = "CREATE"
+ . ($args{'Unique'}? ' UNIQUE' : '')
+ ." INDEX $name ON $args{'Table'}"
+ ."(". join( ', ', @columns ) .")"
+ ;
+
+ my $res = $self->dbh->do( $sql );
+ unless ( $res ) {
+ return (
+ undef, "Failed to create ". $self->IndexDescription( %args )
+ ." (sql: $sql): ". $self->dbh->errstr
+ );
+ }
+ return ($name, "Created ". $self->IndexDescription( %args ) );
+}
+
+sub IndexDescription {
+ my $self = shift;
+ my %args = (@_);
+
+ my $desc =
+ ($args{'Unique'}? 'unique ' : '')
+ .'index'
+ . ($args{'Name'}? " $args{'Name'}" : '')
+ . ( @{$args{'Columns'}||[]}?
+ " ("
+ . join(', ', @{$args{'Columns'}})
+ . (@{$args{'Optional'}||[]}? '['. join(', ', '', @{$args{'Optional'}}).']' : '' )
+ .")"
+ : ''
+ )
+ . ($args{'Table'}? " on $args{'Table'}" : '')
+ ;
+ return $desc;
+}
+
# log a mason stack trace instead of a Carp::longmess because it's less painful
# and uses mason component paths properly
sub _LogSQLStatement {
diff --git a/t/api/db_indexes.t b/t/api/db_indexes.t
new file mode 100644
index 0000000..8453804
--- /dev/null
+++ b/t/api/db_indexes.t
@@ -0,0 +1,126 @@
+use strict;
+use warnings;
+use Test::Warn;
+
+use RT::Test tests => undef;
+
+my $handle = $RT::Handle;
+my $db_type = RT->Config->Get('DatabaseType');
+
+# Pg,Oracle needs DBA
+RT::Test::__reconnect_rt('as dba');
+ok( $handle->dbh->do("ALTER SESSION SET CURRENT_SCHEMA=". RT->Config->Get('DatabaseUser') ) )
+ if $db_type eq 'Oracle';
+
+note "test handle->Indexes method";
+{
+ my %indexes = $handle->Indexes;
+ ok grep $_ eq 'tickets1', @{ $indexes{'tickets'} };
+ ok grep $_ eq 'tickets2', @{ $indexes{'tickets'} };
+ if ($db_type eq 'Oracle') {
+ ok grep $_ eq 'users2', @{ $indexes{'users'} };
+ } else {
+ ok grep $_ eq 'users1', @{ $indexes{'users'} };
+ }
+ ok grep $_ eq 'users4', @{ $indexes{'users'} };
+}
+
+note "test handle->DropIndex method";
+{
+ my ($status, $msg) = $handle->DropIndex( Table => 'Tickets', Name => 'Tickets1' );
+ ok $status, $msg;
+
+ my %indexes = $handle->Indexes;
+ ok !grep $_ eq 'tickets1', @{ $indexes{'tickets'} };
+
+ ($status, $msg) = $handle->DropIndex( Table => 'Tickets', Name => 'Tickets1' );
+ ok !$status, $msg;
+}
+
+note "test handle->DropIndexIfExists method";
+{
+ my ($status, $msg) = $handle->DropIndexIfExists( Table => 'Tickets', Name => 'Tickets2' );
+ ok $status, $msg;
+
+ my %indexes = $handle->Indexes;
+ ok !grep $_ eq 'tickets2', @{ $indexes{'tickets'} };
+
+ ($status, $msg) = $handle->DropIndexIfExists( Table => 'Tickets', Name => 'Tickets2' );
+ ok $status, $msg;
+}
+
+note "test handle->IndexInfo method";
+{
+ if ($db_type ne 'Oracle' && $db_type ne 'mysql') {
+ my %res = $handle->IndexInfo( Table => 'Attachments', Name => 'Attachments1' );
+ is_deeply(
+ \%res,
+ {
+ Table => 'attachments', Name => 'attachments1',
+ Unique => 0, Functional => 0,
+ Columns => ['parent']
+ }
+ );
+ } else {
+ my %res = $handle->IndexInfo( Table => 'Attachments', Name => 'Attachments2' );
+ is_deeply(
+ \%res,
+ {
+ Table => 'attachments', Name => 'attachments2',
+ Unique => 0, Functional => 0,
+ Columns => ['transactionid']
+ }
+ );
+ }
+
+ my %res = $handle->IndexInfo( Table => 'GroupMembers', Name => 'GroupMembers1' );
+ is_deeply(
+ \%res,
+ {
+ Table => 'groupmembers', Name => 'groupmembers1',
+ Unique => 1, Functional => 0,
+ Columns => ['groupid', 'memberid']
+ }
+ );
+
+ if ( $db_type eq 'Pg' || $db_type eq 'Oracle' ) {
+ %res = $handle->IndexInfo( Table => 'Queues', Name => 'Queues1' );
+ is_deeply(
+ \%res,
+ {
+ Table => 'queues', Name => 'queues1',
+ Unique => 1, Functional => 1,
+ Columns => ['name'],
+ CaseInsensitive => { name => 1 },
+ }
+ );
+ }
+}
+
+note "test ->CreateIndex and ->IndexesThatBeginWith methods";
+{
+ {
+ my ($name, $msg) = $handle->CreateIndex(
+ Table => 'Users', Name => 'test_users1',
+ Columns => ['Organization'],
+ );
+ ok $name, $msg;
+ }
+ {
+ my ($name, $msg) = $handle->CreateIndex(
+ Table => 'Users', Name => 'test_users2',
+ Columns => ['Organization', 'Name'],
+ );
+ ok $name, $msg;
+ }
+
+ my @list = $handle->IndexesThatBeginWith( Table => 'Users', Columns => ['Organization'] );
+ is_deeply([sort map $_->{Name}, @list], [qw(test_users1 test_users2)]);
+
+ my ($status, $msg) = $handle->DropIndex( Table => 'Users', Name => 'test_users1' );
+ ok $status, $msg;
+ ($status, $msg) = $handle->DropIndex( Table => 'Users', Name => 'test_users2' );
+ ok $status, $msg;
+}
+
+done_testing();
commit e93efe535e8b3d3c8e63097db957e3eb62e24ff8
Author: Ruslan Zakirov <ruz at bestpractical.com>
Date: Fri Apr 12 12:54:48 2013 +0400
GroupMembers(GroupId, MemberId) index for SQLite
diff --git a/etc/schema.SQLite b/etc/schema.SQLite
index a10a845..53ad06c 100755
--- a/etc/schema.SQLite
+++ b/etc/schema.SQLite
@@ -208,6 +208,8 @@ CREATE TABLE GroupMembers (
) ;
+CREATE UNIQUE INDEX GroupMembers1 ON GroupMembers(GroupId, MemberId);
+
--- }}}
--- {{{ CachedGroupMembers
commit 4b084cfbacb54f8537f086de4fb2aa352b5b0b41
Author: Ruslan Zakirov <ruz at bestpractical.com>
Date: Mon Apr 15 15:01:07 2013 +0400
indexes action in rt-setup-database
This is a separate file that is excuted as perl code
with $dbh connected as DBA. Goal is to give rope to
explore existing indexes during upgrade.
diff --git a/lib/RT/Handle.pm b/lib/RT/Handle.pm
index 9a896fa..8f2f5d8 100644
--- a/lib/RT/Handle.pm
+++ b/lib/RT/Handle.pm
@@ -515,6 +515,33 @@ sub InsertSchema {
return (1);
}
+sub InsertIndexes {
+ my $self = shift;
+ my $dbh = shift;
+ my $base_path = shift || $RT::EtcPath;
+
+ my $db_type = RT->Config->Get('DatabaseType');
+
+ $dbh = $self->dbh if !$dbh && ref $self;
+ return (0, "No DBI handle provided") unless $dbh;
+
+ return (0, "'$base_path' doesn't exist") unless -e $base_path;
+
+ my $path;
+ if ( -d $base_path ) {
+ $path = File::Spec->catfile( $base_path, "indexes");
+ return (0, "Couldn't find indexes file")
+ unless -e $path;
+ } else {
+ $path = $base_path;
+ }
+
+ local $@;
+ eval { require $path; 1 }
+ or return (0, "Couldn't execute '$path': " . $@);
+ return (1);
+}
+
=head1 GetVersionFile
Takes base name of the file as argument, scans for <base name>-<version> named
diff --git a/sbin/rt-setup-database.in b/sbin/rt-setup-database.in
index d9b7418..8ae9284 100644
--- a/sbin/rt-setup-database.in
+++ b/sbin/rt-setup-database.in
@@ -125,7 +125,7 @@ if ( @actions > 1 && $args{'datafile'} ) {
exit(-1);
}
foreach ( @actions ) {
- unless ( /^(?:init|create|drop|schema|acl|coredata|insert|upgrade)$/ ) {
+ unless ( /^(?:init|create|drop|schema|acl|indexes|coredata|insert|upgrade)$/ ) {
print STDERR "$0 called with an invalid --action parameter.\n";
exit(-1);
}
@@ -243,6 +243,17 @@ sub action_acl {
return RT::Handle->InsertACL( $dbh, $args{'datafile'} || $args{'datadir'} );
}
+sub action_indexes {
+ my %args = @_;
+ my $dbh = get_admin_dbh();
+ $RT::Handle = RT::Handle->new;
+ $RT::Handle->dbh( $dbh );
+ RT::InitLogging();
+
+ print "Now inserting database indexes.\n";
+ return RT::Handle->InsertIndexes( $dbh, $args{'datafile'} || $args{'datadir'} );
+}
+
sub action_coredata {
my %args = @_;
$RT::Handle = RT::Handle->new;
@@ -441,6 +452,10 @@ sub action_upgrade {
( $ret, $msg ) = action_acl( %tmp );
return ( $ret, $msg ) unless $ret;
}
+ if ( -e "$base_dir/$v/indexes" ) {
+ ( $ret, $msg ) = action_indexes( %tmp );
+ return ( $ret, $msg ) unless $ret;
+ }
if ( -e "$base_dir/$v/content" ) {
( $ret, $msg ) = action_insert( %tmp );
return ( $ret, $msg ) unless $ret;
commit 9229a6bb7901b3c358d36f1d1bcdab7217bc5a91
Author: Ruslan Zakirov <ruz at bestpractical.com>
Date: Thu May 2 16:13:29 2013 +0400
indexes on Groups table
All queries on Groups table should involve Domain column.
If Domain is not filtered then something is wrong.
We decided to go with case insensitive searches even on
columns where case is "controlled" - it's easier to implement
and isn't slower with proper indexes, so indexes are wrapped
into LOWER() functions for case sensitive DBs.
Type is deprecated and Name should be used, so we index it after
Domain. This covers loading of user defined (Instantless) groups
that were not covered before by any index longer than (Domain).
Log of all queries from an active instance showed that we do queries
like:
Name = A AND ((Domain = B AND Instance = C) OR (Domain = D))
For such queries (Domain, Name) index doesn't provide enough
selectivity. Index on (Instance) can not be used. After all the query
is very selective as Domain = D is part that selects system role group
(4 records top). With (Domain, Name) index DB spends a lot of time
switching between the index and the table to re-check Instance = C
condition. If we have (Domain, Name, Instance) index then, at least
mysql, can skip jumping and just use index to check all conditions
without looking into table data.
Test were performed with SQL from 4.0 instance, but in master (4.2 to be)
we widened use of 1 as Instance value for system groups. This means
that in above query Instance is defined for every ORed branch and more
DBs can use full length of the index.
Instance is very selective column and short (like id), so we just index
it for situations when Type/Name is not defined, but instance is.
Domain, Type, Instance is kept for backwards compatibility and will go
away with Type column.
diff --git a/etc/schema.Oracle b/etc/schema.Oracle
index 3f78236..7e06f07 100755
--- a/etc/schema.Oracle
+++ b/etc/schema.Oracle
@@ -88,8 +88,9 @@ CREATE TABLE Groups (
LastUpdated DATE
-- Instance VARCHAR2(64)
);
-CREATE INDEX Groups1 ON Groups (LOWER(Domain), Instance, LOWER(Type), id);
-CREATE INDEX Groups2 ON Groups (LOWER(Type), Instance, LOWER(Domain));
+CREATE INDEX Groups1 ON Groups (LOWER(Domain), LOWER(Type), Instance);
+CREATE INDEX Groups2 ON Groups (LOWER(Domain), LOWER(Name), Instance);
+CREATE INDEX Groups3 ON Groups (Instance);
CREATE SEQUENCE SCRIPCONDITIONS_seq;
diff --git a/etc/schema.Pg b/etc/schema.Pg
index b0f9662..815b574 100755
--- a/etc/schema.Pg
+++ b/etc/schema.Pg
@@ -144,8 +144,9 @@ CREATE TABLE Groups (
PRIMARY KEY (id)
);
-CREATE UNIQUE INDEX Groups1 ON Groups (Domain,Instance,Type,id, Name);
-CREATE INDEX Groups2 On Groups (Type, Instance, Domain);
+CREATE INDEX Groups1 ON Groups (LOWER(Domain), LOWER(Type), Instance);
+CREATE INDEX Groups2 ON Groups (LOWER(Domain), LOWER(Name), Instance);
+CREATE INDEX Groups3 On Groups (Instance);
diff --git a/etc/schema.SQLite b/etc/schema.SQLite
index 53ad06c..9f9fdbf 100755
--- a/etc/schema.SQLite
+++ b/etc/schema.SQLite
@@ -92,7 +92,9 @@ CREATE TABLE Groups (
) ;
-CREATE UNIQUE INDEX Groups1 ON Groups (Name,Domain,Type,Instance) ;
+CREATE INDEX Groups1 ON Groups (Domain,Type,Instance);
+CREATE INDEX Groups2 ON Groups (Domain,Name,Instance);
+CREATE INDEX Groups3 ON Groups (Instance);
--- }}}
diff --git a/etc/schema.mysql b/etc/schema.mysql
index bed471e..ddef769 100755
--- a/etc/schema.mysql
+++ b/etc/schema.mysql
@@ -88,10 +88,9 @@ CREATE TABLE Groups (
PRIMARY KEY (id)
) ENGINE=InnoDB CHARACTER SET utf8;
-CREATE INDEX Groups1 ON Groups (Domain,Instance,Type,id);
-CREATE INDEX Groups2 On Groups (Type, Instance);
-
-
+CREATE INDEX Groups1 ON Groups (Domain, Type, Instance);
+CREATE INDEX Groups2 ON Groups (Domain, Name, Instance);
+CREATE INDEX Groups3 On Groups (Instance);
CREATE TABLE ScripConditions (
id INTEGER NOT NULL AUTO_INCREMENT,
diff --git a/etc/upgrade/4.1.10/indexes b/etc/upgrade/4.1.10/indexes
new file mode 100644
index 0000000..04342bb
--- /dev/null
+++ b/etc/upgrade/4.1.10/indexes
@@ -0,0 +1,34 @@
+use strict;
+use warnings;
+
+# groups table
+{
+ foreach my $name ( qw(Groups1 Groups2 Groups3) ) {
+ my ($status, $msg) = $RT::Handle->DropIndexIfExists(
+ Table => 'Groups', Name => $name,
+ );
+ RT->Logger->info($msg);
+ }
+
+ my ($name, $msg) = $RT::Handle->CreateIndex(
+ Table => 'Groups',
+ Columns => [qw(Domain Type Instance)],
+ CaseInsensitive => { domain => 1, type => 1 },
+ );
+ RT->Logger->info($msg);
+
+ ($name, $msg) = $RT::Handle->CreateIndex(
+ Table => 'Groups',
+ Columns => [qw(Domain Name Instance)],
+ CaseInsensitive => { domain => 1, name => 1 },
+ );
+ RT->Logger->info($msg);
+
+ ($name, $msg) = $RT::Handle->CreateIndex(
+ Table => 'Groups',
+ Columns => [qw(Instance)],
+ );
+ RT->Logger->info($msg);
+}
+
+1;
commit 03e589c5362c8b9ea743a3dcd5d8d79546b88825
Author: Ruslan Zakirov <ruz at bestpractical.com>
Date: Thu May 2 16:22:14 2013 +0400
unique case insensitive indexes on Queues and Users
make sure we have indexes on Queues(Name) and Users(Name)
and those are unique and are set up for case insensitive
searches (LOWER(...)).
diff --git a/etc/schema.Oracle b/etc/schema.Oracle
index 7e06f07..d8a4471 100755
--- a/etc/schema.Oracle
+++ b/etc/schema.Oracle
@@ -38,7 +38,7 @@ CREATE TABLE Queues (
LastUpdated DATE,
Disabled NUMBER(11,0) DEFAULT 0 NOT NULL
);
- CREATE INDEX Queues1 ON Queues (LOWER(Name));
+CREATE UNIQUE INDEX Queues1 ON Queues (LOWER(Name));
CREATE INDEX Queues2 ON Queues (Disabled);
@@ -251,9 +251,8 @@ CREATE TABLE Users (
LastUpdatedBy NUMBER(11,0) DEFAULT 0 NOT NULL,
LastUpdated DATE
);
--- CREATE UNIQUE INDEX Users1 ON Users (Name);
-CREATE INDEX Users2 ON Users( LOWER(Name));
+CREATE UNIQUE INDEX Users1 ON Users (LOWER(Name));
CREATE INDEX Users4 ON Users (LOWER(EmailAddress));
diff --git a/etc/schema.Pg b/etc/schema.Pg
index 815b574..698323e 100755
--- a/etc/schema.Pg
+++ b/etc/schema.Pg
@@ -63,7 +63,7 @@ CREATE TABLE Queues (
PRIMARY KEY (id)
);
-CREATE UNIQUE INDEX Queues1 ON Queues (Name) ;
+CREATE UNIQUE INDEX Queues1 ON Queues (LOWER(Name)) ;
@@ -395,7 +395,7 @@ CREATE TABLE Users (
);
-CREATE UNIQUE INDEX Users1 ON Users (Name) ;
+CREATE UNIQUE INDEX Users1 ON Users (LOWER(Name)) ;
CREATE INDEX Users3 ON Users (id, EmailAddress);
CREATE INDEX Users4 ON Users (EmailAddress);
diff --git a/etc/schema.SQLite b/etc/schema.SQLite
index 9f9fdbf..6bfc1a0 100755
--- a/etc/schema.SQLite
+++ b/etc/schema.SQLite
@@ -277,7 +277,6 @@ CREATE TABLE Users (
CREATE UNIQUE INDEX Users1 ON Users (Name) ;
-CREATE INDEX Users2 ON Users (Name);
CREATE INDEX Users3 ON Users (id, EmailAddress);
CREATE INDEX Users4 ON Users (EmailAddress);
diff --git a/etc/upgrade/4.1.10/indexes b/etc/upgrade/4.1.10/indexes
index 04342bb..d0a7133 100644
--- a/etc/upgrade/4.1.10/indexes
+++ b/etc/upgrade/4.1.10/indexes
@@ -31,4 +31,38 @@ use warnings;
RT->Logger->info($msg);
}
+# a few case insensitive and unique indexes
+{
+ my @list = (
+ { Table => 'Queues', Column => 'Name' },
+ { Table => 'Users', Column => 'Name' },
+ );
+ foreach my $e (@list) {
+ RT->Logger->info("Checking index on ". $e->{'Column'} ." in ". $e->{'Table'} );
+ my ($index) = $RT::Handle->IndexesThatBeginWith(
+ Table => $e->{'Table'}, Columns => [$e->{'Column'}]
+ );
+ $index = undef if $index && @{$index->{'Columns'}}>1;
+ if (
+ $index && $index->{'Unique'}
+ && ($RT::Handle->CaseSensitive? $index->{'CaseInsensitive'}{ lc $e->{'Column'} } : 1 )
+ ) {
+ RT->Logger->info("Required index exists. Skipping.");
+ next;
+ }
+ if ( $index ) {
+ my ($status, $msg) = $RT::Handle->DropIndex(
+ Table => $e->{'Table'}, Name => $index->{'Name'},
+ );
+ RT->Logger->info($msg);
+ }
+
+ my ($status, $msg) = $RT::Handle->CreateIndex(
+ Table => $e->{'Table'}, Columns => [$e->{'Column'}],
+ Unique => 1, CaseInsensitive => { lc $e->{'Column'} => 1 },
+ );
+ RT->Logger->info($msg);
+ }
+}
+
1;
commit 0e8c28b31e057c3a608be83dcfae109d0d4d271e
Author: Ruslan Zakirov <ruz at bestpractical.com>
Date: Fri May 3 19:16:35 2013 +0400
indexes on cached group members
CachedGroupMembers (CGM) table is mostly pass through
table when we either have GroupId and need MemberId or
have MemberId and need GroupId.
We also filter by Disabled column in most cases and don't
in some, but selectivity of Disabled column is very small,
so we put it as last.
Some DBs (mysql, newer Pg, most probably Oracle) can use
index to complete select without looking into table itself,
so we create index for both case mentioned above with Disabled
on the tail.
Also, we make sure (MemberId, ImmediateParentId) is indexed
which is used when we delete members from Groups.
diff --git a/etc/schema.Oracle b/etc/schema.Oracle
index d8a4471..84e795b 100755
--- a/etc/schema.Oracle
+++ b/etc/schema.Oracle
@@ -207,7 +207,7 @@ CREATE TABLE CachedGroupMembers (
Disabled NUMBER(11,0) DEFAULT 0 NOT NULL
);
CREATE INDEX DisGrouMem ON CachedGroupMembers (GroupId, MemberId, Disabled);
-CREATE INDEX GrouMem ON CachedGroupMembers (GroupId, MemberId);
+CREATE INDEX CachedGroupMembers2 ON CachedGroupMembers (MemberId, GroupId, Disabled);
CREATE INDEX CachedGroupMembers3 on CachedGroupMembers (MemberId, ImmediateParentId);
diff --git a/etc/schema.Pg b/etc/schema.Pg
index 698323e..ec297c8 100755
--- a/etc/schema.Pg
+++ b/etc/schema.Pg
@@ -337,9 +337,9 @@ CREATE TABLE CachedGroupMembers (
);
-CREATE INDEX CachedGroupMembers2 on CachedGroupMembers (MemberId);
-CREATE INDEX CachedGroupMembers3 on CachedGroupMembers (GroupId);
-CREATE INDEX DisGrouMem on CachedGroupMembers (GroupId,MemberId,Disabled);
+CREATE INDEX CachedGroupMembers2 on CachedGroupMembers (MemberId, GroupId, Disabled);
+CREATE INDEX DisGrouMem on CachedGroupMembers (GroupId,MemberId,Disabled);
+CREATE INDEX CachedGroupMembers3 on CachedGroupMembers (MemberId,ImmediateParentId);
diff --git a/etc/schema.SQLite b/etc/schema.SQLite
index 6bfc1a0..f83d2ef 100755
--- a/etc/schema.SQLite
+++ b/etc/schema.SQLite
@@ -231,6 +231,10 @@ create table CachedGroupMembers (
) ;
+CREATE INDEX CachedGroupMembers1 (GroupId, MemberId, Disabled);
+CREATE INDEX CachedGroupMembers2 (MemberId, GroupId, Disabled);
+CREATE INDEX CachedGroupMembers3 (MemberId, ImmediateParentId);
+
--- }}}
--- {{{ Users
diff --git a/etc/schema.mysql b/etc/schema.mysql
index ddef769..fe6314d 100755
--- a/etc/schema.mysql
+++ b/etc/schema.mysql
@@ -217,6 +217,7 @@ create table CachedGroupMembers (
) ENGINE=InnoDB CHARACTER SET utf8;
CREATE INDEX DisGrouMem on CachedGroupMembers (GroupId,MemberId,Disabled);
+CREATE INDEX CachedGroupMembers2 on CachedGroupMembers (MemberId, GroupId, Disabled);
CREATE INDEX CachedGroupMembers3 on CachedGroupMembers (MemberId, ImmediateParentId);
diff --git a/etc/upgrade/4.1.10/indexes b/etc/upgrade/4.1.10/indexes
index d0a7133..0a7ed2e 100644
--- a/etc/upgrade/4.1.10/indexes
+++ b/etc/upgrade/4.1.10/indexes
@@ -65,4 +65,90 @@ use warnings;
}
}
+# cached group members
+{
+ MakeSureIndexExists(
+ Table => 'CachedGroupMembers',
+ Columns => ['MemberId', 'ImmediateParentId'],
+ );
+ MakeSureIndexExists(
+ Table => 'CachedGroupMembers',
+ Columns => ['MemberId', 'GroupId'],
+ Optional => ['Disabled'],
+ );
+ DropIndexesThatArePrefix(
+ Table => 'CachedGroupMembers',
+ Columns => ['MemberId', 'GroupId', 'Disabled'],
+ );
+ MakeSureIndexExists(
+ Table => 'CachedGroupMembers',
+ Columns => ['GroupId', 'MemberId'],
+ Optional => ['Disabled'],
+ );
+ DropIndexesThatArePrefix(
+ Table => 'CachedGroupMembers',
+ Columns => ['GroupId', 'MemberId', 'Disabled'],
+ );
+}
+
+
+sub MakeSureIndexExists {
+ my %args = ( Table => undef, Columns => [], Optional => [], @_ );
+
+ my @list = $RT::Handle->IndexesThatBeginWith(
+ Table => $args{'Table'}, Columns => [@{$args{'Columns'}}, @{$args{'Optional'}}],
+ );
+ if (@list) {
+ RT->Logger->info( ucfirst $RT::Handle->IndexDescription(
+ Table => $args{'Table'}, Columns => [@{$args{'Columns'}}, @{$args{'Optional'}}],
+ ). ' exists.' );
+ return;
+ }
+
+ @list = $RT::Handle->IndexesThatBeginWith(
+ Table => $args{'Table'}, Columns => $args{'Columns'},
+ );
+ if ( !@list ) {
+ my ($status, $msg) = $RT::Handle->CreateIndex(
+ Table => $args{'Table'}, Columns => [@{$args{'Columns'}}, @{$args{'Optional'}}],
+ );
+ RT->Logger->info($msg);
+ }
+ else {
+ RT->Logger->info(
+ ucfirst $RT::Handle->IndexDescription(
+ %{$list[0]}
+ )
+ .' exists, you may consider replacing it with '
+ . $RT::Handle->IndexDescription(
+ Table => $args{'Table'}, Columns => [@{$args{'Columns'}}, @{$args{'Optional'}}],
+ )
+ );
+ }
+}
+
+sub DropIndexesThatArePrefix {
+ my %args = ( Table => undef, Columns => [], @_ );
+
+ my @list = $RT::Handle->IndexesThatBeginWith(
+ Table => $args{'Table'}, Columns => [$args{'Columns'}[0]],
+ );
+
+ my $checking = join ',', map lc $_, @{ $args{'Columns'} }, '';
+ foreach my $i ( splice @list ) {
+ my $columns = join ',', @{ $i->{'Columns'} }, '';
+ next unless $checking =~ /^\Q$columns/i;
+
+ push @list, $i;
+ }
+ pop @list;
+
+ foreach my $i ( @list ) {
+ my ($status, $msg) = $RT::Handle->DropIndex(
+ Table => $i->{'Table'}, Name => $i->{'Name'},
+ );
+ RT->Logger->info($msg);
+ }
+}
+
1;
commit 4ecc53b1df3b686893a3b2518e154a55cb95fcde
Author: Ruslan Zakirov <ruz at bestpractical.com>
Date: Mon May 6 16:17:46 2013 +0400
drop indexes that start from id
indexes that start from PK are very useless.
Mysql just don't use any such index, but primary key. Pg acts
similary. It's harder to check Oracle. Even if SQLite behaves
differently (hardly so) it doesn't matter much, for we this
for consistency.
diff --git a/etc/schema.Oracle b/etc/schema.Oracle
index 84e795b..85e5d02 100755
--- a/etc/schema.Oracle
+++ b/etc/schema.Oracle
@@ -288,8 +288,6 @@ CREATE TABLE Tickets (
);
CREATE INDEX Tickets1 ON Tickets (Queue, Status);
CREATE INDEX Tickets2 ON Tickets (Owner);
-CREATE INDEX Tickets4 ON Tickets (id, Status);
-CREATE INDEX Tickets5 ON Tickets (id, EffectiveId);
CREATE INDEX Tickets6 ON Tickets (EffectiveId, Type);
diff --git a/etc/schema.Pg b/etc/schema.Pg
index ec297c8..0e366f6 100755
--- a/etc/schema.Pg
+++ b/etc/schema.Pg
@@ -396,7 +396,6 @@ CREATE TABLE Users (
CREATE UNIQUE INDEX Users1 ON Users (LOWER(Name)) ;
-CREATE INDEX Users3 ON Users (id, EmailAddress);
CREATE INDEX Users4 ON Users (EmailAddress);
@@ -448,13 +447,6 @@ CREATE TABLE Tickets (
CREATE INDEX Tickets1 ON Tickets (Queue, Status) ;
CREATE INDEX Tickets2 ON Tickets (Owner) ;
CREATE INDEX Tickets3 ON Tickets (EffectiveId) ;
-CREATE INDEX Tickets4 ON Tickets (id, Status) ;
-CREATE INDEX Tickets5 ON Tickets (id, EffectiveId) ;
-
-
-
-
-
--
diff --git a/etc/schema.SQLite b/etc/schema.SQLite
index f83d2ef..394bca2 100755
--- a/etc/schema.SQLite
+++ b/etc/schema.SQLite
@@ -281,7 +281,6 @@ CREATE TABLE Users (
CREATE UNIQUE INDEX Users1 ON Users (Name) ;
-CREATE INDEX Users3 ON Users (id, EmailAddress);
CREATE INDEX Users4 ON Users (EmailAddress);
@@ -324,8 +323,6 @@ CREATE TABLE Tickets (
CREATE INDEX Tickets1 ON Tickets (Queue, Status) ;
CREATE INDEX Tickets2 ON Tickets (Owner) ;
CREATE INDEX Tickets3 ON Tickets (EffectiveId) ;
-CREATE INDEX Tickets4 ON Tickets (id, Status) ;
-CREATE INDEX Tickets5 ON Tickets (id, EffectiveId) ;
--- }}}
diff --git a/etc/upgrade/4.1.10/indexes b/etc/upgrade/4.1.10/indexes
index 0a7ed2e..8f0ce10 100644
--- a/etc/upgrade/4.1.10/indexes
+++ b/etc/upgrade/4.1.10/indexes
@@ -91,6 +91,21 @@ use warnings;
);
}
+# drop indexes that start with 'id' column
+foreach my $table ('Users', 'Tickets') {
+ my @list = $RT::Handle->IndexesThatBeginWith(
+ Table => $table, Columns => ['id'],
+ );
+ @list = grep @{ $_->{'Columns'} } > 1, @list;
+
+ foreach my $index (@list) {
+ my ($status, $msg) = $RT::Handle->DropIndex(
+ Table => $table, Name => $index->{'Name'},
+ );
+ RT->Logger->info($msg);
+ }
+}
+
sub MakeSureIndexExists {
my %args = ( Table => undef, Columns => [], Optional => [], @_ );
-----------------------------------------------------------------------
More information about the Rt-commit
mailing list