[Rt-commit] rt branch, 3.9-fts, updated. rt-3.9.4-34-g35347d9

Ruslan Zakirov ruz at bestpractical.com
Thu Oct 7 13:33:42 EDT 2010


The branch, 3.9-fts has been updated
       via  35347d98aa7f2d1b85640cb78039426861640f20 (commit)
       via  be6130c50317fa6af44c78e37c0e3118ac3c9da1 (commit)
       via  b30fb36d0db46854a94fd5b8ff233f50ad2055e1 (commit)
       via  129e3f3f62ac7ec5bad94564229456d1ffac7205 (commit)
      from  dceeb2377ab6721e11e09f17cf558e5811b20a31 (commit)

Summary of changes:
 .gitignore                      |    1 +
 Makefile.in                     |    4 +-
 configure.ac                    |    2 +-
 sbin/rt-fts-oracle.in           |  420 -------------------------
 sbin/rt-setup-fulltext-index.in |  660 +++++++++++++++++++++++++++++++++++++++
 t/fts/indexed_pg.t              |   84 +++++
 6 files changed, 748 insertions(+), 423 deletions(-)
 delete mode 100755 sbin/rt-fts-oracle.in
 create mode 100644 sbin/rt-setup-fulltext-index.in
 create mode 100644 t/fts/indexed_pg.t

- Log -----------------------------------------------------------------
commit 129e3f3f62ac7ec5bad94564229456d1ffac7205
Author: Ruslan Zakirov <ruz at bestpractical.com>
Date:   Wed Oct 6 18:39:58 2010 +0400

    we have only one schema for mysql these days

diff --git a/Makefile.in b/Makefile.in
index 679a2e7..9970f0d 100755
--- a/Makefile.in
+++ b/Makefile.in
@@ -183,8 +183,7 @@ ETC_FILES		=	acl.Informix \
 				schema.Informix \
 				schema.Pg \
 				schema.Oracle \
-				schema.mysql-4.0 \
-				schema.mysql-4.1 \
+				schema.mysql \
 				schema.Sybase \
 				schema.SQLite \
 				initialdata

commit b30fb36d0db46854a94fd5b8ff233f50ad2055e1
Author: Ruslan Zakirov <ruz at bestpractical.com>
Date:   Wed Oct 6 18:57:23 2010 +0400

    delete sbin/rt-fts-oracle.in, we will have one script

diff --git a/sbin/rt-fts-oracle.in b/sbin/rt-fts-oracle.in
deleted file mode 100755
index d2a7bf2..0000000
--- a/sbin/rt-fts-oracle.in
+++ /dev/null
@@ -1,420 +0,0 @@
-#!@PERL@
-# BEGIN BPS TAGGED BLOCK {{{
-#
-# COPYRIGHT:
-#
-# This software is Copyright (c) 1996-2010 Best Practical Solutions, LLC
-#                                          <jesse at bestpractical.com>
-#
-# (Except where explicitly superseded by other copyright notices)
-#
-#
-# LICENSE:
-#
-# This work is made available to you under the terms of Version 2 of
-# the GNU General Public License. A copy of that license should have
-# been provided with this software, but in any event can be snarfed
-# from www.gnu.org.
-#
-# This work 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-1301 or visit their web page on the internet at
-# http://www.gnu.org/licenses/old-licenses/gpl-2.0.html.
-#
-#
-# CONTRIBUTION SUBMISSION POLICY:
-#
-# (The following paragraph is not intended to limit the rights granted
-# to you to modify and distribute this software under the terms of
-# the GNU General Public License and is only of importance to you if
-# you choose to contribute your changes and enhancements to the
-# community by submitting them to Best Practical Solutions, LLC.)
-#
-# By intentionally submitting any modifications, corrections or
-# derivatives to this work, or any other work intended for use with
-# Request Tracker, to Best Practical Solutions, LLC, you confirm that
-# you are the copyright holder for those contributions and you grant
-# Best Practical Solutions,  LLC a nonexclusive, worldwide, irrevocable,
-# royalty-free, perpetual, license to use, copy, create derivative
-# works based on those contributions, and sublicense and distribute
-# those contributions and any derivatives thereof.
-#
-# END BPS TAGGED BLOCK }}}
-use strict;
-use warnings;
-no warnings 'once';
-
-# fix lib paths, some may be relative
-BEGIN {
-    require File::Spec;
-    my @libs = ("@RT_LIB_PATH@", "@LOCAL_LIB_PATH@");
-    my $bin_path;
-
-    for my $lib (@libs) {
-        unless ( File::Spec->file_name_is_absolute($lib) ) {
-            unless ($bin_path) {
-                if ( File::Spec->file_name_is_absolute(__FILE__) ) {
-                    $bin_path = ( File::Spec->splitpath(__FILE__) )[1];
-                }
-                else {
-                    require FindBin;
-                    no warnings "once";
-                    $bin_path = $FindBin::Bin;
-                }
-            }
-            $lib = File::Spec->catfile( $bin_path, File::Spec->updir, $lib );
-        }
-        unshift @INC, $lib;
-    }
-
-}
-
-=head1 NAME
-
-rt-fts-oracle - setup Oracle Text index for full text search
-
-=head1 USAGE
-
-    rt-fts-oracle --help
-    rt-fts-oracle --dba sysdba --dba-password 'secret'
-
-=head1 DESCRIPTION
-
-This utility grants CTXAPP role to RT's user and rights to execute functions
-from CTX_DDL package. Also, it creates several prefernces, functions and triggers
-all starting with 'rt_fts_' prefix in the name. After all an index is created.
-
-=cut
-
-use RT;
-RT::LoadConfig();
-
-my %DB = (
-    user           => $RT::DatabaseUser,
-    admin          => undef,
-    admin_password => undef,
-);
-
-my %OPT = (
-    help        => 0,
-);
-
-use Getopt::Long qw(GetOptions);
-GetOptions(
-    'h|help!'        => \$OPT{'help'},
-    'dba=s'          => \$DB{'admin'},
-    'dba-password=s' => \$DB{'admin_password'},
-);
-
-if ( $OPT{'help'} || !$DB{'admin'}) {
-    require Pod::Usage;
-    Pod::Usage::pod2usage(
-        -message => "",
-        -exitval => $OPT{'help'}? 0 : 1,
-        -verbose => 99,
-        -sections => $OPT{'help'}? 'NAME|USAGE|DESCRIPTION|OPTIONS' : 'NAME|USAGE',
-    );
-}
-
-RT::Init();
-
-{
-    my $dbah = dba_handle();
-    do_print_error( $dbah => 'GRANT CTXAPP TO '. $DB{'user'} );
-    do_print_error( $dbah => 'GRANT EXECUTE ON CTXSYS.CTX_DDL TO '. $DB{'user'} );
-}
-
-my $dbh = $RT::Handle->dbh;
-$dbh->{'RaiseError'} = 1;
-$dbh->{'PrintError'} = 1;
-
-my $prefix = 'rt_fts_';
-
-our %PREFERENCES = (
-    datastore => {
-        type => 'DIRECT_DATASTORE',
-    },
-    filter => {
-        type => 'AUTO_FILTER',
-#        attributes => {
-#            timeout => 120, # seconds
-#            timeout_type => 'HEURISTIC', # or 'FIXED'
-#        },
-    },
-    lexer => {
-        type => 'WORLD_LEXER',
-    },
-    word_list => {
-        type => 'BASIC_WORDLIST',
-        attributes => {
-            stemmer => 'AUTO',
-            fuzzy_match => 'AUTO',
-#            fuzzy_score => undef,
-#            fuzzy_numresults => undef,
-#            substring_index => undef,
-#            prefix_index => undef,
-#            prefix_length_min => undef,
-#            prefix_length_max => undef,
-#            wlidcard_maxterms => undef,
-        },
-    },
-    'section_group' => {
-        type => 'NULL_SECTION_GROUP',
-    },
-
-    storage => {
-        type => 'BASIC_STORAGE',
-        attributes => {
-            R_TABLE_CLAUSE => 'lob (data) store as (cache)',
-            I_INDEX_CLAUSE => 'compress 2',
-        },
-    },
-);
-
-my @params = ();
-push @params, create_datastore();
-push @params, create_filter();
-push @params, create_lexer();
-push @params, create_word_list();
-push @params, create_stop_list();
-push @params, create_section_group();
-push @params, create_storage();
-
-my $index_params = join "\n", @params;
-do_error_is_ok( $dbh => "DROP INDEX ${prefix}index" );
-$dbh->do(
-    "CREATE INDEX ${prefix}index ON Attachments(Content)
-    indextype is ctxsys.context parameters('
-        $index_params
-    ')",
-);
-
-sub create_datastore {
-    return sprintf 'datastore %s', create_preference(
-        %{ $PREFERENCES{'datastore'} },
-        name => 'datastore',
-    );
-}
-
-sub create_filter {
-    my $res = '';
-    $res .= sprintf "format column %s\n", create_format_column();
-    $res .= sprintf 'filter %s', create_preference(
-        %{ $PREFERENCES{'filter'} },
-        name => 'filter',
-    );
-    return $res;
-}
-
-sub create_lexer {
-    return sprintf 'lexer %s', create_preference(
-        %{ $PREFERENCES{'lexer'} },
-        name => 'lexer',
-    );
-}
-
-sub create_word_list {
-    return sprintf 'wordlist %s', create_preference(
-        %{ $PREFERENCES{'word_list'} },
-        name => 'word_list',
-    );
-}
-
-sub create_stop_list {
-    my $file = shift || 'etc/stopwords/en.txt';
-
-    my $name = $prefix .'stop_list';
-    do_error_is_ok( $dbh => 'begin ctx_ddl.drop_stoplist(?); end;', $name );
-    
-    $dbh->do(
-        'begin ctx_ddl.create_stoplist(?, ?);  end;',
-        undef, $name, 'BASIC_STOPLIST'
-    );
-
-    open my $fh, '<:utf8', $file
-        or die "couldn't open file '$file': $!";
-    while ( my $word = <$fh> ) {
-        chomp $word;
-        $dbh->do(
-            'begin ctx_ddl.add_stopword(?, ?); end;',
-            undef, $name, $word
-        );
-    }
-    close $fh;
-    return sprintf 'stoplist %s', $name;
-}
-
-sub create_section_group {
-    my $name = $prefix .'section_group';
-    do_error_is_ok( $dbh => 'begin ctx_ddl.drop_section_group(?); end;', $name );
-    $dbh->do(
-        'begin ctx_ddl.create_section_group(?, ?);  end;',
-        undef, $name, $PREFERENCES{'section_group'}{'type'}
-    );
-    return sprintf 'section group %s', $name;
-}
-
-sub create_storage {
-    return sprintf 'storage %s', create_preference(
-        %{ $PREFERENCES{'storage'} },
-        name => 'storage',
-    );
-}
-
-sub create_format_column {
-    my $column_name = 'ContentOracleFormat';
-    unless (
-        $dbh->column_info(
-            undef, undef, uc('Attachments'), uc( $column_name )
-        )->fetchrow_array
-    ) {
-        $dbh->do(qq{
-            ALTER TABLE Attachments ADD $column_name VARCHAR2(10)
-        });
-    }
-
-    my $detect_format = qq{
-        CREATE OR REPLACE FUNCTION ${prefix}detect_format_simple(
-            parent IN NUMBER,
-            type IN VARCHAR2,
-            encoding IN VARCHAR2,
-            fname IN VARCHAR2
-        )
-        RETURN VARCHAR2
-        AS
-            format VARCHAR2(10);
-        BEGIN
-            format := CASE
-    };
-    if ( $RT::DontSearchFileAttachments ) {
-        $detect_format .= qq{
-                WHEN fname IS NOT NULL THEN 'ignore'
-        };
-    }
-    my $binary = $RT::DontSearchBinaryAttachments? 'ignore' : 'binary';
-    $detect_format .= qq{
-                WHEN type = 'text' THEN 'text'
-                WHEN type = 'text/rtf' THEN '$binary'
-                WHEN type LIKE 'text/%' THEN 'text'
-                WHEN type LIKE 'message/%' THEN 'text'
-                WHEN type LIKE 'multipart/%' THEN 'ignore'
-                WHEN type LIKE 'image/%' THEN 'ignore'
-                WHEN type LIKE 'audio/%' THEN 'ignore'
-                WHEN type LIKE 'video/%' THEN 'ignore'
-                WHEN type LIKE '%signature%' THEN 'ignore'
-                WHEN type LIKE '%pkcs7%' THEN 'ignore'
-                WHEN type LIKE '%compress%' THEN 'ignore'
-                WHEN type LIKE '%zip%' THEN 'ignore'
-                WHEN type LIKE '%tar%' THEN 'ignore'
-                WHEN type LIKE '%/octet-stream' THEN 'ignore'
-                ELSE '$binary'
-            END;
-            RETURN format;
-        END;
-    };
-    create_procedure( $detect_format );
-
-    $dbh->do(qq{
-        UPDATE Attachments
-        SET $column_name = ${prefix}detect_format_simple(
-            Parent,
-            ContentType, ContentEncoding,
-            Filename
-        )
-        WHERE $column_name IS NULL
-    });
-    $dbh->do(qq{
-        CREATE OR REPLACE TRIGGER ${prefix}set_format
-        BEFORE INSERT
-        ON Attachments
-        FOR EACH ROW
-        BEGIN
-            :new.$column_name := ${prefix}detect_format_simple(
-                :new.Parent,
-                :new.ContentType, :new.ContentEncoding,
-                :new.Filename
-            );
-        END;
-    });
-    return $column_name;
-}
-
-sub create_preference {
-    my %info = @_;
-    my $name = $prefix . $info{'name'};
-    do_error_is_ok( $dbh => 'begin ctx_ddl.drop_preference(?); end;', $name );
-    $dbh->do(
-        'begin ctx_ddl.create_preference(?, ?);  end;',
-        undef, $name, $info{'type'}
-    );
-    return $name unless $info{'attributes'};
-
-    while ( my ($attr, $value) = each %{ $info{'attributes'} } ) {
-        $dbh->do(
-            'begin ctx_ddl.set_attribute(?, ?, ?);  end;',
-            undef, $name, $attr, $value
-        );
-    }
-
-    return $name;
-}
-
-sub create_procedure {
-    my $text = shift;
-
-    my $status = $dbh->do($text, { RaiseError => 0 });
-
-    # Statement succeeded
-    return if $status;
-
-    if ( 6550 != $dbh->err ) {
-        # Utter failure
-        die $dbh->errstr;
-    }
-    else {
-        my $msg = $dbh->func( 'plsql_errstr' );
-        die $dbh->errstr if !defined $msg;
-        die $msg if $msg;
-    }
-}
-
-sub dba_handle {
-    $ENV{'NLS_LANG'} = "AMERICAN_AMERICA.AL32UTF8";
-    $ENV{'NLS_NCHAR'} = "AL32UTF8";
-    my $dsn = do { my $h = new RT::Handle; $h->BuildDSN; $h->DSN };
-    my $dbh = DBI->connect(
-        $dsn, $DB{admin}, $DB{admin_password},
-        { RaiseError => 1, PrintError => 1 },
-    );
-    unless ( $dbh ) {
-        die "Failed to connect to $dsn as user '$DB{admin}': ". $DBI::errstr;
-    }
-    return $dbh;
-}
-
-sub do_error_is_ok {
-    my $dbh = shift;
-    local $dbh->{'RaiseError'} = 0;
-    local $dbh->{'PrintError'} = 0;
-    return $dbh->do(shift, undef, @_);
-}
-
-sub do_print_error {
-    my $dbh = shift;
-    local $dbh->{'RaiseError'} = 0;
-    local $dbh->{'PrintError'} = 1;
-    return $dbh->do(shift, undef, @_);
-}
-
-=head1 AUTHOR
-
-Ruslan Zakirov E<lt>ruz at bestpractical.comE<gt>
-
-=cut
-

commit be6130c50317fa6af44c78e37c0e3118ac3c9da1
Author: Ruslan Zakirov <ruz at bestpractical.com>
Date:   Thu Oct 7 00:56:40 2010 +0400

    sbin/rt-setup-fulltext-index

diff --git a/.gitignore b/.gitignore
index 484ff94..365790d 100644
--- a/.gitignore
+++ b/.gitignore
@@ -28,6 +28,7 @@ sbin/rt-fts-oracle
 sbin/rt-server
 sbin/rt-session-viewer
 sbin/rt-setup-database
+sbin/rt-setup-fulltext-index
 sbin/rt-shredder
 sbin/rt-test-dependencies
 sbin/rt-validator
diff --git a/Makefile.in b/Makefile.in
index 9970f0d..fda6efc 100755
--- a/Makefile.in
+++ b/Makefile.in
@@ -164,6 +164,7 @@ BINARIES		=	$(RT_MODPERL_HANDLER) \
 SYSTEM_BINARIES		=	rt-attributes-viewer \
 				rt-dump-database \
 				rt-setup-database \
+				rt-setup-fulltext-index \
 				rt-email-digest \
 				rt-email-dashboards \
 				rt-email-group-admin \
diff --git a/configure.ac b/configure.ac
index c6502f6..3b50f69 100755
--- a/configure.ac
+++ b/configure.ac
@@ -413,7 +413,7 @@ AC_CONFIG_FILES([
                  sbin/rt-validator
                  sbin/rt-email-group-admin
                  sbin/rt-server
-                 sbin/rt-fts-oracle
+                 sbin/rt-setup-fulltext-index
                  bin/fastcgi_server
                  bin/mason_handler.fcgi
                  bin/mason_handler.scgi
diff --git a/sbin/rt-setup-fulltext-index.in b/sbin/rt-setup-fulltext-index.in
new file mode 100644
index 0000000..e04660a
--- /dev/null
+++ b/sbin/rt-setup-fulltext-index.in
@@ -0,0 +1,660 @@
+#!@PERL@
+# BEGIN BPS TAGGED BLOCK {{{
+#
+# COPYRIGHT:
+#
+# This software is Copyright (c) 1996-2010 Best Practical Solutions, LLC
+#                                          <jesse at bestpractical.com>
+#
+# (Except where explicitly superseded by other copyright notices)
+#
+#
+# LICENSE:
+#
+# This work is made available to you under the terms of Version 2 of
+# the GNU General Public License. A copy of that license should have
+# been provided with this software, but in any event can be snarfed
+# from www.gnu.org.
+#
+# This work 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-1301 or visit their web page on the internet at
+# http://www.gnu.org/licenses/old-licenses/gpl-2.0.html.
+#
+#
+# CONTRIBUTION SUBMISSION POLICY:
+#
+# (The following paragraph is not intended to limit the rights granted
+# to you to modify and distribute this software under the terms of
+# the GNU General Public License and is only of importance to you if
+# you choose to contribute your changes and enhancements to the
+# community by submitting them to Best Practical Solutions, LLC.)
+#
+# By intentionally submitting any modifications, corrections or
+# derivatives to this work, or any other work intended for use with
+# Request Tracker, to Best Practical Solutions, LLC, you confirm that
+# you are the copyright holder for those contributions and you grant
+# Best Practical Solutions,  LLC a nonexclusive, worldwide, irrevocable,
+# royalty-free, perpetual, license to use, copy, create derivative
+# works based on those contributions, and sublicense and distribute
+# those contributions and any derivatives thereof.
+#
+# END BPS TAGGED BLOCK }}}
+use strict;
+use warnings;
+no warnings 'once';
+
+# fix lib paths, some may be relative
+BEGIN {
+    require File::Spec;
+    my @libs = ("@RT_LIB_PATH@", "@LOCAL_LIB_PATH@");
+    my $bin_path;
+
+    for my $lib (@libs) {
+        unless ( File::Spec->file_name_is_absolute($lib) ) {
+            unless ($bin_path) {
+                if ( File::Spec->file_name_is_absolute(__FILE__) ) {
+                    $bin_path = ( File::Spec->splitpath(__FILE__) )[1];
+                }
+                else {
+                    require FindBin;
+                    no warnings "once";
+                    $bin_path = $FindBin::Bin;
+                }
+            }
+            $lib = File::Spec->catfile( $bin_path, File::Spec->updir, $lib );
+        }
+        unshift @INC, $lib;
+    }
+}
+
+use RT;
+RT::LoadConfig();
+
+my %DB = (
+    type           => scalar RT->Config->Get('DatabaseType'),
+    user           => scalar RT->Config->Get('DatabaseUser'),
+    admin          => undef,
+    admin_password => undef,
+);
+
+my %OPT = (
+    help        => 0,
+    ask         => 1,
+);
+
+my %DEFAULT;
+if ( $DB{'type'} eq 'Pg' ) {
+    %DEFAULT = (
+        table  => 'Attachments',
+        column => 'ContentIndex',
+    );
+}
+elsif ( $DB{'type'} eq 'mysql' ) {
+    %DEFAULT = (
+        table => 'AttachmentsIndex',
+        column => 'Content',
+    );
+}
+elsif ( $DB{'type'} eq 'Oracle' ) {
+    %DEFAULT = (
+        prefix => 'rt_fts_',
+    );
+}
+
+use Getopt::Long qw(GetOptions);
+GetOptions(
+    'h|help!'        => \$OPT{'help'},
+    'ask!'           => \$OPT{'ask'},
+
+    'dba=s'          => \$DB{'admin'},
+    'dba-password=s' => \$DB{'admin_password'},
+);
+
+if ( $OPT{'help'} || (!$DB{'admin'} && $DB{'type'} eq 'Oracle' ) ) {
+    show_help( !$OPT{'help'} );
+}
+
+RT::Init();
+
+my $dbh = $RT::Handle->dbh;
+$dbh->{'RaiseError'} = 1;
+$dbh->{'PrintError'} = 1;
+
+if ( $DB{'type'} eq 'mysql' ) {
+    my $dbh = Jifty->handle->dbh;
+
+    check_sphinx();
+    my $table = prompt(
+        message => 'Enter name of a DB table that will be used to connect to the sphinx server',
+        default => $DEFAULT{'table'},
+        silent  => !$OPT{'ask'},
+    );
+    my $url = prompt(
+        message => 'Enter URL of the sphinx search server, it should be sphinx://<server>:<port>/<index name>. Simple config for this sphinx instance will be generated for you.',
+        default => 'sphinx://localhost:3312/rt',
+        silent  => !$OPT{'ask'},
+    );
+
+    my $schema = <<END;
+CREATE TABLE $table (
+    id     INTEGER NOT NULL,
+    weight INTEGER NOT NULL,
+    $DEFAULT{'column'}  VARCHAR(3072) NOT NULL,
+    INDEX($DEFAULT{'column'})
+) ENGINE=SPHINX CONNECTION="$url"
+END
+
+    print_rt_config( table => $table, column => $DEFAULT{'column'} );
+    insert_schema( $schema );
+
+    require URI;
+    my $urlo = URI->new( $url );
+    my $host  = $urlo->host;
+    my $port  = $urlo->port;
+    my $index = $urlo->path;
+
+    my $var_path = RT->var_path;
+
+    my %sphinx_conf = ();
+    $sphinx_conf{'host'} = RT->config->get('DatabaseHost');
+    $sphinx_conf{'db'}   = RT->config->get('DatabaseName');
+    $sphinx_conf{'user'} = RT->config->get('DatabaseUser');
+    $sphinx_conf{'pass'} = RT->config->get('DatabasePassword');
+
+    print "Here is simple sphinx config, you can use it to index text/plain attachments in your DB."
+        ." This config is not ideal. You should read Sphinx docs to get better ideas.";
+    print <<END
+
+source rt {
+    type            = mysql
+
+    sql_host        = $sphinx_conf{'host'}
+    sql_db          = $sphinx_conf{'db'}
+    sql_user        = $sphinx_conf{'user'}
+    sql_pass        = $sphinx_conf{'pass'}
+
+    sql_query       = \
+        SELECT a.id, a.content FROM Attachments a
+        JOIN Transactions txn ON a.transaction_id = txn.id AND txn.object_type = 'RT::Model::Ticket' \
+        JOIN Tickets t ON txn.object_id = t.id \
+        WHERE a.content_type = 'text/plain' AND t.Status != 'deleted'
+
+    sql_query_info  = SELECT * FROM Attachments WHERE id=\$id
+}
+
+index \$index {
+    source                  = rt
+    path                    = $var_path/sphinx/index
+    docinfo                 = extern
+    charset_type            = utf-8
+}
+
+indexer {
+    mem_limit               = 32M
+}
+
+searchd {
+    port                    = $port
+    log                     = $var_path/sphinx/searchd.log
+    query_log               = $var_path/sphinx/query.log
+    read_timeout            = 5
+    max_children            = 30
+    pid_file                = $var_path/sphinx/searchd.pid
+    max_matches             = 1000
+    seamless_rotate         = 1
+    preopen_indexes         = 0
+    unlink_old              = 1
+}
+
+END
+
+}
+elsif ( $DB{'type'} eq 'Pg' ) {
+    my $dbh = $RT::Handle->dbh;
+
+    my $table = prompt(
+        message => 'Enter name of a DB table that will be used to connect to the sphinx server',
+        default => $DEFAULT{'table'},
+        silent  => !$OPT{'ask'},
+    );
+
+    my $schema = <<END;
+CREATE TABLE $table (
+    id      INTEGER NOT NULL,
+    $DEFAULT{'column'} tsvector
+)
+END
+
+    print_rt_config( table => $table, column => $DEFAULT{'column'} );
+
+    insert_schema( $schema );
+
+    print <<END;
+Now you have to create an index on the column. You have choice
+between GiST or GIN, the first is times slower to search, but
+it takes less place and faster to update. Anyway, both are faster
+then searches without them.
+
+Either run:
+
+    CREATE INDEX $DEFAULT{column}_idx ON $table USING gin($DEFAULT{'column'});
+
+or
+
+    CREATE INDEX $DEFAULT{column}_idx ON $table USING gist($DEFAULT{'column'});
+
+END
+}
+elsif ( $DB{'type'} eq 'Oracle' ) {
+    {
+        my $dbah = dba_handle();
+        do_print_error( $dbah => 'GRANT CTXAPP TO '. $DB{'user'} );
+        do_print_error( $dbah => 'GRANT EXECUTE ON CTXSYS.CTX_DDL TO '. $DB{'user'} );
+    }
+
+    my %PREFERENCES = (
+        datastore => {
+            type => 'DIRECT_DATASTORE',
+        },
+        filter => {
+            type => 'AUTO_FILTER',
+#        attributes => {
+#            timeout => 120, # seconds
+#            timeout_type => 'HEURISTIC', # or 'FIXED'
+#        },
+        },
+        lexer => {
+            type => 'WORLD_LEXER',
+        },
+        word_list => {
+            type => 'BASIC_WORDLIST',
+            attributes => {
+                stemmer => 'AUTO',
+                fuzzy_match => 'AUTO',
+#            fuzzy_score => undef,
+#            fuzzy_numresults => undef,
+#            substring_index => undef,
+#            prefix_index => undef,
+#            prefix_length_min => undef,
+#            prefix_length_max => undef,
+#            wlidcard_maxterms => undef,
+            },
+        },
+        'section_group' => {
+            type => 'NULL_SECTION_GROUP',
+        },
+
+        storage => {
+            type => 'BASIC_STORAGE',
+            attributes => {
+                R_TABLE_CLAUSE => 'lob (data) store as (cache)',
+                I_INDEX_CLAUSE => 'compress 2',
+            },
+        },
+    );
+
+    my @params = ();
+    push @params, ora_create_datastore( %{ $PREFERENCES{'datastore'} } );
+    push @params, ora_create_filter( %{ $PREFERENCES{'filter'} } );
+    push @params, ora_create_lexer( %{ $PREFERENCES{'lexer'} } );
+    push @params, ora_create_word_list( %{ $PREFERENCES{'word_list'} } );
+    push @params, ora_create_stop_list();
+    push @params, ora_create_section_group( %{ $PREFERENCES{'section_group'} } );
+    push @params, ora_create_storage( %{ $PREFERENCES{'storage'} } );
+
+    my $index_params = join "\n", @params;
+    do_error_is_ok( $dbh => "DROP INDEX $DEFAULT{prefix}index" );
+    $dbh->do(
+        "CREATE INDEX $DEFAULT{prefix}index ON Attachments(Content)
+        indextype is ctxsys.context parameters('
+            $index_params
+        ')",
+    );
+
+}
+else {
+    die "FTS on $DB{type} is not yet supported"; 
+}
+
+sub check_sphinx {
+    my $dbh = $RT::Handle->dbh;
+    my $sphinx = ($dbh->selectrow_array("show variables like 'have_sphinx'"))[1];
+    unless ( lc $sphinx eq 'yes' ) {
+        print STDERR "Mysql server you have compiled without sphinx storage engine (sphinxse).\n";
+        print STDERR "Either use system packages with sphinxse, binaries from Sphinx site
+                      or compile mysql according to instructions in Sphinx's docs.\n";
+        exit 1;
+    }
+}
+
+sub ora_create_datastore {
+    return sprintf 'datastore %s', create_preference(
+        @_,
+        name => 'datastore',
+    );
+}
+
+sub ora_create_filter {
+    my $res = '';
+    $res .= sprintf "format column %s\n", create_format_column();
+    $res .= sprintf 'filter %s', create_preference(
+        @_,
+        name => 'filter',
+    );
+    return $res;
+}
+
+sub ora_create_lexer {
+    return sprintf 'lexer %s', create_preference(
+        @_,
+        name => 'lexer',
+    );
+}
+
+sub ora_create_word_list {
+    return sprintf 'wordlist %s', create_preference(
+        @_,
+        name => 'word_list',
+    );
+}
+
+sub ora_create_stop_list {
+    my $file = shift || 'etc/stopwords/en.txt';
+
+    my $name = $ora_prefix .'stop_list';
+    do_error_is_ok( $dbh => 'begin ctx_ddl.drop_stoplist(?); end;', $name );
+    
+    $dbh->do(
+        'begin ctx_ddl.create_stoplist(?, ?);  end;',
+        undef, $name, 'BASIC_STOPLIST'
+    );
+
+    open my $fh, '<:utf8', $file
+        or die "couldn't open file '$file': $!";
+    while ( my $word = <$fh> ) {
+        chomp $word;
+        $dbh->do(
+            'begin ctx_ddl.add_stopword(?, ?); end;',
+            undef, $name, $word
+        );
+    }
+    close $fh;
+    return sprintf 'stoplist %s', $name;
+}
+
+sub ora_create_section_group {
+    my %args = @_;
+    my $name = $ora_prefix .'section_group';
+    do_error_is_ok( $dbh => 'begin ctx_ddl.drop_section_group(?); end;', $name );
+    $dbh->do(
+        'begin ctx_ddl.create_section_group(?, ?);  end;',
+        undef, $name, $args{'type'}
+    );
+    return sprintf 'section group %s', $name;
+}
+
+sub ora_create_storage {
+    return sprintf 'storage %s', create_preference(
+        @_,
+        name => 'storage',
+    );
+}
+
+sub ora_create_format_column {
+    my $column_name = 'ContentOracleFormat';
+    unless (
+        $dbh->column_info(
+            undef, undef, uc('Attachments'), uc( $column_name )
+        )->fetchrow_array
+    ) {
+        $dbh->do(qq{
+            ALTER TABLE Attachments ADD $column_name VARCHAR2(10)
+        });
+    }
+
+    my $detect_format = qq{
+        CREATE OR REPLACE FUNCTION $DEFAULT{prefix}detect_format_simple(
+            parent IN NUMBER,
+            type IN VARCHAR2,
+            encoding IN VARCHAR2,
+            fname IN VARCHAR2
+        )
+        RETURN VARCHAR2
+        AS
+            format VARCHAR2(10);
+        BEGIN
+            format := CASE
+    };
+    if ( $RT::DontSearchFileAttachments ) {
+        $detect_format .= qq{
+                WHEN fname IS NOT NULL THEN 'ignore'
+        };
+    }
+    my $binary = $RT::DontSearchBinaryAttachments? 'ignore' : 'binary';
+    $detect_format .= qq{
+                WHEN type = 'text' THEN 'text'
+                WHEN type = 'text/rtf' THEN '$binary'
+                WHEN type LIKE 'text/%' THEN 'text'
+                WHEN type LIKE 'message/%' THEN 'text'
+                WHEN type LIKE 'multipart/%' THEN 'ignore'
+                WHEN type LIKE 'image/%' THEN 'ignore'
+                WHEN type LIKE 'audio/%' THEN 'ignore'
+                WHEN type LIKE 'video/%' THEN 'ignore'
+                WHEN type LIKE '%signature%' THEN 'ignore'
+                WHEN type LIKE '%pkcs7%' THEN 'ignore'
+                WHEN type LIKE '%compress%' THEN 'ignore'
+                WHEN type LIKE '%zip%' THEN 'ignore'
+                WHEN type LIKE '%tar%' THEN 'ignore'
+                WHEN type LIKE '%/octet-stream' THEN 'ignore'
+                ELSE '$binary'
+            END;
+            RETURN format;
+        END;
+    };
+    create_procedure( $detect_format );
+
+    $dbh->do(qq{
+        UPDATE Attachments
+        SET $column_name = $DEFAULT{prefix}detect_format_simple(
+            Parent,
+            ContentType, ContentEncoding,
+            Filename
+        )
+        WHERE $column_name IS NULL
+    });
+    $dbh->do(qq{
+        CREATE OR REPLACE TRIGGER $DEFAULT{prefix}set_format
+        BEFORE INSERT
+        ON Attachments
+        FOR EACH ROW
+        BEGIN
+            :new.$column_name := $DEFAULT{prefix}detect_format_simple(
+                :new.Parent,
+                :new.ContentType, :new.ContentEncoding,
+                :new.Filename
+            );
+        END;
+    });
+    return $column_name;
+}
+
+sub ora_create_preference {
+    my %info = @_;
+    my $name = $ora_prefix . $info{'name'};
+    do_error_is_ok( $dbh => 'begin ctx_ddl.drop_preference(?); end;', $name );
+    $dbh->do(
+        'begin ctx_ddl.create_preference(?, ?);  end;',
+        undef, $name, $info{'type'}
+    );
+    return $name unless $info{'attributes'};
+
+    while ( my ($attr, $value) = each %{ $info{'attributes'} } ) {
+        $dbh->do(
+            'begin ctx_ddl.set_attribute(?, ?, ?);  end;',
+            undef, $name, $attr, $value
+        );
+    }
+
+    return $name;
+}
+
+sub ora_create_procedure {
+    my $text = shift;
+
+    my $status = $dbh->do($text, { RaiseError => 0 });
+
+    # Statement succeeded
+    return if $status;
+
+    if ( 6550 != $dbh->err ) {
+        # Utter failure
+        die $dbh->errstr;
+    }
+    else {
+        my $msg = $dbh->func( 'plsql_errstr' );
+        die $dbh->errstr if !defined $msg;
+        die $msg if $msg;
+    }
+}
+
+sub dba_handle {
+    if ( $DB{'type'} eq 'Oracle' ) {
+        $ENV{'NLS_LANG'} = "AMERICAN_AMERICA.AL32UTF8";
+        $ENV{'NLS_NCHAR'} = "AL32UTF8";
+    }
+    my $dsn = do { my $h = new RT::Handle; $h->BuildDSN; $h->DSN };
+    my $dbh = DBI->connect(
+        $dsn, $DB{admin}, $DB{admin_password},
+        { RaiseError => 1, PrintError => 1 },
+    );
+    unless ( $dbh ) {
+        die "Failed to connect to $dsn as user '$DB{admin}': ". $DBI::errstr;
+    }
+    return $dbh;
+}
+
+sub do_error_is_ok {
+    my $dbh = shift;
+    local $dbh->{'RaiseError'} = 0;
+    local $dbh->{'PrintError'} = 0;
+    return $dbh->do(shift, undef, @_);
+}
+
+sub do_print_error {
+    my $dbh = shift;
+    local $dbh->{'RaiseError'} = 0;
+    local $dbh->{'PrintError'} = 1;
+    return $dbh->do(shift, undef, @_);
+}
+
+sub prompt {
+    my %args = ( @_ );
+    return $args{'default'} if $args{'silent'};
+
+    local $| = 1;
+    print $args{'message'};
+    if ( $args{'default'} ) {
+        print "\n[". $args{'default'} .']: ';
+    } else {
+        print ":\n";
+    }
+
+    my $res = <STDIN>;
+    chomp $res;
+    return $args{'default'} if !$res && $args{'default'};
+    return $res;
+}
+
+sub verbose  { print @_, "\n" if $OPT{verbose} || $OPT{verbose}; 1 }
+sub debug    { print @_, "\n" if $OPT{debug}; 1 }
+sub error    { $RT::Logger->error( @_ ); verbose(@_); 1 }
+sub warning  { $RT::Logger->warning( @_ ); verbose(@_); 1 }
+
+sub show_help {
+    my $error = shift;
+    require Pod::Usage;
+    Pod::Usage::pod2usage(
+        -message => "",
+        -exitval => $error || 0, 
+        -verbose => 99,
+        -sections => $error
+            ? 'NAME|'. lc($DB{'type'}) .'/USAGE'
+            : 'NAME|'. lc($DB{'type'}),
+    );
+}
+
+sub print_rt_config {
+    my %args = @_;
+    my $config = <<END;
+
+Configure your RT via site config:
+Set( %FullTextSearch,
+    Enable  => 1,
+    Indexed => 1,
+END
+
+    $config .= "    Table   => '$args{'table'}',\n" if $args{'table'};
+    $config .= "    Column  => '$args{'column'}',\n" if $args{'column'};
+    $config .= ");\n";
+
+    print $config;
+}
+
+sub insert_schema {
+    my $schema = shift;
+    print "Going to do the following change in the DB:\n";
+    print $schema;
+    return if $OPT{'dryrun'};
+
+    my $res = $dbh->do( $schema );
+    unless ( $res ) {
+        die "Couldn't create the table: ". $dbh->errstr;
+    }
+}
+
+=head1 NAME
+
+rt-setup-fulltext-index - Helps create indexes for full text search
+
+=head1 ORACLE
+
+=head2 USAGE
+
+    rt-setup-fulltext-index --help
+    rt-setup-fulltext-index --dba sysdba --dba-password 'secret'
+
+=head2 DESCRIPTION
+
+This utility grants CTXAPP role to RT's user and rights to execute functions
+from CTX_DDL package. Also, it creates several prefernces, functions and triggers
+all starting with 'rt_fts_' prefix in the name. After all an index is created.
+
+=head1 PG
+
+=head2 USAGE
+
+    rt-setup-fulltext-index --help
+
+=head2 DESCRIPTION
+
+=head1 MYSQL
+
+=head2 USAGE
+
+    rt-setup-fulltext-index --help
+
+=head2 DESCRIPTION
+
+=head1 AUTHOR
+
+Ruslan Zakirov E<lt>ruz at bestpractical.comE<gt>
+
+=cut
+

commit 35347d98aa7f2d1b85640cb78039426861640f20
Author: Ruslan Zakirov <ruz at bestpractical.com>
Date:   Thu Oct 7 00:57:12 2010 +0400

    t/fts/indexed_pg.t

diff --git a/t/fts/indexed_pg.t b/t/fts/indexed_pg.t
new file mode 100644
index 0000000..51c585d
--- /dev/null
+++ b/t/fts/indexed_pg.t
@@ -0,0 +1,84 @@
+#!/usr/bin/perl -w
+
+use strict;
+use warnings;
+
+use RT::Test tests => undef;
+plan skip_all => 'Not Pg' unless RT->Config->Get('DatabaseType') eq 'Pg';
+plan tests => 100;
+
+setup_indexing();
+
+RT->Config->Set( FullTextSearch => Enable => 1, Indexed => 1 );
+
+my $q = RT::Test->load_or_create_queue( Name => 'General' );
+ok $q && $q->id, 'loaded or created queue';
+my $queue = $q->Name;
+
+my ($total, @data, @tickets, @test, @conditions) = (0, ());
+
+sub setup_indexing {
+    my %args = (
+        command => $RT::SbinPath .'/rt-setup-fulltext-index',
+    );
+    my ($exit_code, $output) = RT::Test->run_and_capture( %args );
+    ok(!$exit_code, "setted up index") or diag "output: $output";
+}
+
+sub add_tix_from_data {
+    my @res = ();
+    while (@data) {
+        my $t = RT::Ticket->new(RT->SystemUser);
+        my ( $id, undef $msg ) = $t->Create(
+            Queue => $q->id,
+            %{ shift(@data) },
+        );
+        ok( $id, "ticket created" ) or diag("error: $msg");
+        push @res, $t;
+        $total++;
+    }
+    return @res;
+}
+
+sub run_tests {
+    while ( my ($query, $checks) = splice @test, 0, 2 ) {
+        run_test( $query, %$checks );
+    }
+}
+
+sub run_test {
+    my ($query, %checks) = @_;
+    my $query_prefix = join ' OR ', map 'id = '. $_->id, @tickets;
+
+    my $tix = RT::Tickets->new(RT->SystemUser);
+    $tix->FromSQL( "( $query_prefix ) AND ( $query )" );
+
+    my $error = 0;
+
+    my $count = 0;
+    $count++ foreach grep $_, values %checks;
+    is($tix->Count, $count, "found correct number of ticket(s) by '$query'") or $error = 1;
+
+    my $good_tickets = ($tix->Count == $count);
+    while ( my $ticket = $tix->Next ) {
+        next if $checks{ $ticket->Subject };
+        diag $ticket->Subject ." ticket has been found when it's not expected";
+        $good_tickets = 0;
+    }
+    ok( $good_tickets, "all tickets are good with '$query'" ) or $error = 1;
+
+    diag "Wrong SQL query for '$query':". $tix->BuildSelectQuery if $error;
+}
+
+ at data = (
+    { Subject => 'foo', Content => 'foo' },
+    { Subject => 'bar', Content => 'bar' },
+);
+ at tickets = add_tix_from_data();
+
+ at test = (
+    "Content LIKE 'foo'" => { foo => 1, bar => 0 },
+    "Content LIKE 'bar'" => { foo => 0, bar => 1 },
+);
+run_tests();
+

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


More information about the Rt-commit mailing list