Skip to content

Commit

Permalink
Only search Content, not Content and Subject, for better indexing
Browse files Browse the repository at this point in the history
A TicketSQL query of « Subject LIKE 'word' OR Content LIKE 'word' »
generates the following SQL (simplified):

    SELECT DISTINCT main.*
      FROM Tickets main
           JOIN Transactions Transactions_1
             ON ( Transactions_1.ObjectType = 'RT::Ticket' )
            AND ( Transactions_1.ObjectId = main.id )
      LEFT JOIN Attachments Attachments_2
             ON ( Attachments_2.TransactionId = Transactions_1.id )
     WHERE main.Subject LIKE '%word%'
        OR Attachments_2.Content MATCHES 'word'

This leaves both MySQL and Postgres unable to use their full-text-search
indexes on the Content search, as their query planner cannot separate
this unto a union of two queries which are both well-indexed.  Instead,
both databases elect to perform sequential scans of all three involved
tables.  While the full-text index does speed this process, the
sequential scans nonethless cause the query to take noticable time.

For the common case of simple search with FTS enabled, default to
searching the Content rather than suffer the performance penalties of
searching both.  In nearly all cases, the words of the subject are
contained within the words of the content; later work will ensure that
the full-text-search index contains the information from the subject,
allowing a performant but fully inclusive search.
  • Loading branch information
alexmv committed Feb 4, 2015
1 parent 155e7d5 commit 8450f0a
Showing 1 changed file with 1 addition and 1 deletion.
2 changes: 1 addition & 1 deletion lib/RT/Search/Simple.pm
Original file line number Diff line number Diff line change
Expand Up @@ -245,7 +245,7 @@ sub GuessType {
sub HandleDefault {
my $fts = RT->Config->Get('FullTextSearch');
if ($fts->{Enable} and $fts->{Indexed}) {
return default => "(Subject LIKE '$_[1]' OR Content LIKE '$_[1]')";
return default => "Content LIKE '$_[1]'";
} else {
return default => "Subject LIKE '$_[1]'";
}
Expand Down

2 comments on commit 8450f0a

@crazy4chrissi
Copy link

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

I am using MariaDB 10.0.25 and Sphinxsearch 2.2.9 for fulltext search and reverting this change did not cause any performance problems so far. The attachments table has 6 GB and without fulltext search, it took minutes to do a fulltext search. So it seems that MariaDB is able to plan this query efficiently?

@crazy4chrissi
Copy link

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Okay, sorry - I just found out that reverting this change causes MariaDB to only search within the subject... :-(
But anyway, I think it should be configurable where the simple search should search by default.

Please sign in to comment.