[Rt-commit] rt branch, 4.2/optimize-cgm-table, updated. rt-4.0.5-312-g2441aff

Ruslan Zakirov ruz at bestpractical.com
Tue Mar 27 19:55:28 EDT 2012


The branch, 4.2/optimize-cgm-table has been updated
       via  2441affbf34ff22d24324948b7e35be8f0c2b8c1 (commit)
      from  14cf36f5d3a0fd761f623aba38a2029a0468c313 (commit)

Summary of changes:
 etc/schema.Oracle               |    5 +--
 etc/schema.Pg                   |    9 +----
 etc/schema.SQLite               |    4 ++-
 etc/schema.mysql                |    4 +-
 etc/upgrade/4.1.0/content       |   67 +++++++++++++++++++++++++++++++++++++++
 etc/upgrade/4.1.0/schema.Oracle |    2 +
 etc/upgrade/4.1.0/schema.Pg     |    2 +
 etc/upgrade/4.1.0/schema.mysql  |    2 +
 lib/RT/CachedGroupMember.pm     |   34 ++++++++++++++++++-
 9 files changed, 114 insertions(+), 15 deletions(-)
 create mode 100644 etc/upgrade/4.1.0/schema.Oracle
 create mode 100644 etc/upgrade/4.1.0/schema.Pg
 create mode 100644 etc/upgrade/4.1.0/schema.mysql

- Log -----------------------------------------------------------------
commit 2441affbf34ff22d24324948b7e35be8f0c2b8c1
Author: Ruslan Zakirov <ruz at bestpractical.com>
Date:   Wed Mar 28 03:54:39 2012 +0400

    upgrade script and new set of indexes
    
    explanation in CGM.pm

diff --git a/etc/schema.Oracle b/etc/schema.Oracle
index 6d5dab8..678efc5 100755
--- a/etc/schema.Oracle
+++ b/etc/schema.Oracle
@@ -190,9 +190,8 @@ CREATE TABLE CachedGroupMembers (
 	MemberId	NUMBER(11,0) NOT NULL,
 	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 CachedGroupMembers3 on CachedGroupMembers (MemberId, ImmediateParentId);
+CREATE UNIQUE INDEX CGM1 ON CachedGroupMembers (GroupId, MemberId, Disabled);
+CREATE UNIQUE INDEX CGM2 ON CachedGroupMembers (MemberId, GroupId, Disabled);
 
 
 CREATE SEQUENCE USERS_seq;
diff --git a/etc/schema.Pg b/etc/schema.Pg
index d2a4c7d..8b25db6 100755
--- a/etc/schema.Pg
+++ b/etc/schema.Pg
@@ -318,13 +318,8 @@ CREATE TABLE CachedGroupMembers (
 
 );
 
-CREATE INDEX CachedGroupMembers2 on CachedGroupMembers (MemberId);
-CREATE INDEX CachedGroupMembers3 on CachedGroupMembers (GroupId);
-CREATE INDEX DisGrouMem  on CachedGroupMembers (GroupId,MemberId,Disabled); 
-
-
-
-
+CREATE UNIQUE INDEX CGM1 ON CachedGroupMembers (GroupId,MemberId);
+CREATE INDEX CGM2 ON CachedGroupMembers (MemberId);
 
 
 
diff --git a/etc/schema.SQLite b/etc/schema.SQLite
index 4b27a2f..2fe28e7 100755
--- a/etc/schema.SQLite
+++ b/etc/schema.SQLite
@@ -208,9 +208,11 @@ create table CachedGroupMembers (
                                            # group members recursively.
                                            # Also, this allows us to have the ACL system elide members of disabled groups
 
-        
 ) ;
 
+CREATE UNIQUE INDEX CGM1 ON CachedGroupMembers (GroupId,MemberId,Disabled);
+CREATE UNIQUE INDEX CGM2 ON CachedGroupMembers (MemberId,GroupId,Disabled);
+
 --- }}}
 
 --- {{{ Users
diff --git a/etc/schema.mysql b/etc/schema.mysql
index 27a87bf..d2a5f5e 100755
--- a/etc/schema.mysql
+++ b/etc/schema.mysql
@@ -201,8 +201,8 @@ create table CachedGroupMembers (
 
 # we can create UNIQUE ON (GroupId,MemberId), but it only a few bytes shorter than
 # the following and there is no need to do that
-CREATE UNIQUE INDEX DisGrouMem  on CachedGroupMembers (GroupId,MemberId,Disabled);
-CREATE UNIQUE INDEX CachedGroupMembers3  on CachedGroupMembers (MemberId,GroupId,Disabled);
+CREATE UNIQUE INDEX CGM1 ON CachedGroupMembers (GroupId,MemberId,Disabled);
+CREATE UNIQUE INDEX CGM2 ON CachedGroupMembers (MemberId,GroupId,Disabled);
 
 
 CREATE TABLE Users (
diff --git a/etc/upgrade/4.1.0/content b/etc/upgrade/4.1.0/content
index 80783eb..4da8f41 100644
--- a/etc/upgrade/4.1.0/content
+++ b/etc/upgrade/4.1.0/content
@@ -20,6 +20,73 @@
         $settings->{sidebar} = delete $settings->{summary};
         $default_portlets->SetContent($settings);
     },
+    sub {
+        # delete disabled duplicate CGM records in favor of active
+        my $status = $RT::Handle->DeleteFromSelect('CachedGroupMembers', <<END);
+SELECT main.id FROM CachedGroupMembers main
+WHERE
+    main.Disabled != 0
+    NOT EXISTS (
+        SELECT 1 FROM CachedGroupMembers CGM
+        WHERE CGM.GroupId = main.GroupId
+            AND CGM.MemberId = main.MemberId
+            AND CGM.id != main.id
+            AND CGM.Disabled = 0
+    )
+END
+        unless ( $status ) {
+            RT->Logger->error("Couldn't delete CGM records");
+            return;
+        }
+
+        # delete other duplicates
+        $status = $RT::Handle->DeleteFromSelect('CachedGroupMembers', <<END);
+SELECT main.id FROM CachedGroupMembers main
+WHERE EXISTS (
+    SELECT 1 FROM CachedGroupMembers CGM
+    WHERE CGM.GroupId = main.GroupId
+        AND CGM.MemberId = main.MemberId
+        AND CGM.id < main.id
+)
+END
+        unless ( $status ) {
+            RT->Logger->error("Couldn't delete CGM records");
+            return;
+        }
+
+        my $dbh = $RT::Handle->dbh;
+        local $dbh->{'RaiseError'} = 0;
+        local $dbh->{'PrintError'} = 1;
+
+        foreach my $index (qw(
+            CachedGroupMembers2 CachedGroupMembers3
+            DisGrouMem GrouMem
+        )) {
+            $dbh->do("DROP INDEX $index ON CachedGroupMembers")
+                or $dbh->do("ALTER TABLE CachedGroupMembers DROP INDEX $index");
+        }
+
+        # see CGM.pm for explanation
+        unless ( RT->Config->Get('DatabaseType') eq 'Pg' ) {
+            $dbh->do(
+                "CREATE UNIQUE INDEX CGM1"
+                ." ON CachedGroupMembers(GroupId, MemberId, Disabled)"
+            );
+            $dbh->do(
+                "CREATE UNIQUE INDEX CGM2"
+                ." ON CachedGroupMembers(MemberId, GroupId, Disabled)"
+            );
+        } else {
+            $dbh->do(
+                "CREATE UNIQUE INDEX CGM1"
+                ." ON CachedGroupMembers(GroupId, MemberId)"
+            );
+            $dbh->do(
+                "CREATE INDEX CGM2"
+                ." ON CachedGroupMembers(MemberId)"
+            );
+        }
+    },
 );
 
 
diff --git a/etc/upgrade/4.1.0/schema.Oracle b/etc/upgrade/4.1.0/schema.Oracle
new file mode 100644
index 0000000..135719e
--- /dev/null
+++ b/etc/upgrade/4.1.0/schema.Oracle
@@ -0,0 +1,2 @@
+ALTER TABLE CachedGroupMembers DROP COLUMN Via;
+ALTER TABLE CachedGroupMembers DROP COLUMN ImmediateParentId;
\ No newline at end of file
diff --git a/etc/upgrade/4.1.0/schema.Pg b/etc/upgrade/4.1.0/schema.Pg
new file mode 100644
index 0000000..135719e
--- /dev/null
+++ b/etc/upgrade/4.1.0/schema.Pg
@@ -0,0 +1,2 @@
+ALTER TABLE CachedGroupMembers DROP COLUMN Via;
+ALTER TABLE CachedGroupMembers DROP COLUMN ImmediateParentId;
\ No newline at end of file
diff --git a/etc/upgrade/4.1.0/schema.mysql b/etc/upgrade/4.1.0/schema.mysql
new file mode 100644
index 0000000..135719e
--- /dev/null
+++ b/etc/upgrade/4.1.0/schema.mysql
@@ -0,0 +1,2 @@
+ALTER TABLE CachedGroupMembers DROP COLUMN Via;
+ALTER TABLE CachedGroupMembers DROP COLUMN ImmediateParentId;
\ No newline at end of file
diff --git a/lib/RT/CachedGroupMember.pm b/lib/RT/CachedGroupMember.pm
index 630e43d..d3540bf 100644
--- a/lib/RT/CachedGroupMember.pm
+++ b/lib/RT/CachedGroupMember.pm
@@ -835,10 +835,40 @@ Now we can re-enable records which still have active paths:
 
 Enabling records is much easier, just update all candidates.
 
+=head2 INDEXING
+
+=head3 Access patterns
+
+We either have group and want members, have member and want groups or
+have both and check existance.
+
+Disabled column has low selectivity.
+
+=head3 Index access without table access
+
+Some databases can access index by prefix and use rest as data source, so
+multi column indexes improve performance.
+
+This works on L<mysql (see "using index")|http://dev.mysql.com/doc/refman/5.1/en/explain-output.html#explain-output-columns>
+and L<Oracle|http://docs.oracle.com/cd/A58617_01/server.804/a58246/access.htm#2174>.
+
+This doesn't work for Pg, but L<comes in 9.2|http://rhaas.blogspot.com/2011/10/fast-counting.html>.
+
+=head3 Indexes
+
+For Oracle, mysql and SQLite:
+
+    UNIQUE ON (GroupId, MemberId, Disabled)
+    UNIQUE ON (MemberId, GroupId, Disabled)
+
+For Pg:
+
+    UNIQUE ON (GroupId, MemberId)
+    (MemberId)
+
 =head2 TODO
 
-Update rt-validator and shredder. Review indexes on all databases.
-Create upgrade script.
+Update shredder.
 
 =head2 What's next
 

-----------------------------------------------------------------------


More information about the Rt-commit mailing list