SQLite support, including EXPLAIN and FTS4 fulltext search

hinted-selects
Vitaliy Filippov 2014-10-24 19:01:10 +04:00
parent 353f14aab8
commit c4c2ec3378
18 changed files with 792 additions and 37 deletions

View File

@ -1641,7 +1641,7 @@ sub _sync_fulltext
$nopriv = join "\n", @$nopriv;
$priv = join "\n", @$priv;
my $row = [ $short_desc, $nopriv, $priv ];
# Determine if we are using Sphinx or MySQL fulltext search
# Determine if we are using Sphinx or MySQL/PostgreSQL/SQLite fulltext search
my ($sph, $id_field);
my $index = Bugzilla->localconfig->{sphinx_index};
my $table = $index;
@ -1656,7 +1656,7 @@ sub _sync_fulltext
{
$table = 'bugs_fulltext';
$sph = $dbh;
$id_field = 'bug_id';
$id_field = $dbh->FULLTEXT_ID_FIELD;
$_ = $dbh->quote_fulltext($_) for @$row;
}
my $sql;
@ -1683,7 +1683,7 @@ sub remove_from_db
$dbh->do("DELETE FROM bugs WHERE bug_id = ?", undef, $self->id);
# The only table that requires manual delete cascading is bugs_fulltext (MyISAM)
$dbh->do("DELETE FROM bugs_fulltext WHERE bug_id = ?", undef, $self->id);
$dbh->do("DELETE FROM bugs_fulltext WHERE ".$dbh->FULLTEXT_ID_FIELD." = ?", undef, $self->id);
# Now this bug no longer exists
$self->DESTROY;
@ -3530,11 +3530,11 @@ sub GetBugActivity
" WHERE a.bug_id = ? $datepart $attachpart $suppwhere";
if (!$attach_id)
{
$query = "($query) UNION ALL (SELECT 'longdesc' field_name, 0 field_desc, null, " . $dbh->sql_date_format('a.bug_when') .
$query = "$query UNION ALL SELECT 'longdesc' field_name, 0 field_desc, null, " . $dbh->sql_date_format('a.bug_when') .
" bug_when, a.oldthetext removed, a.thetext added, profile1.login_name, a.comment_id, a.comment_count".
" FROM longdescs_history a".
" INNER JOIN profiles profile1 ON profile1.userid = a.who".
" WHERE a.bug_id = ? $datepart)";
" WHERE a.bug_id = ? $datepart";
}
$query .= " ORDER BY bug_when, field_desc";

View File

@ -269,7 +269,7 @@ sub Send
my @dep_args = ($id, $start || $creation_ts, $end);
my $when_restriction = ' AND bug_when > ? AND bug_when <= ?';
my $diffs = $dbh->selectall_arrayref(
"(SELECT profiles.login_name, profiles.realname, fielddefs.description fielddesc,
"SELECT profiles.login_name, profiles.realname, fielddefs.description fielddesc,
fielddefs.sortkey fieldsortkey,
bugs_activity.bug_when, bugs_activity.removed,
bugs_activity.added, bugs_activity.attach_id, fielddefs.name fieldname, null as comment_id, null as comment_count
@ -279,8 +279,8 @@ sub Send
INNER JOIN profiles
ON profiles.userid = bugs_activity.who
WHERE bugs_activity.bug_id = ?
$when_restriction)
UNION ALL (SELECT profile1.login_name, profile1.realname, fielddefs1.description fielddesc,
$when_restriction
UNION ALL SELECT profile1.login_name, profile1.realname, fielddefs1.description fielddesc,
fielddefs1.sortkey fieldsortkey,
lh.bug_when, lh.oldthetext removed, lh.thetext added, null, fielddefs1.name fieldname, lh.comment_id, lh.comment_count
FROM longdescs_history lh
@ -289,7 +289,7 @@ sub Send
INNER JOIN fielddefs fielddefs1
ON fielddefs1.name = 'longdesc'
WHERE lh.bug_id = ?
$when_restriction)
$when_restriction
ORDER BY bug_when, fieldsortkey", {Slice=>{}}, @args, @args);
my @new_depbugs;

View File

@ -63,7 +63,7 @@ sub check
}
}
@$sql || return [];
$sql = "(" . join(") UNION ALL (", @$sql) . ")";
$sql = join(" UNION ALL ", @$sql);
$sql = Bugzilla->dbh->prepare_cached($sql);
$sql->execute(@bind);
my $checked = [];
@ -103,19 +103,20 @@ sub alert
}
else
{
my $dbh = Bugzilla->dbh;
# Some checks failed. Roll changes back.
$bug->{passed_checkers} = 0;
# bugs_fulltext is non-transactional...
if ($is_new)
{
Bugzilla->dbh->do('DELETE FROM bugs_fulltext WHERE bug_id=?', undef, $bug->bug_id);
$dbh->do('DELETE FROM bugs_fulltext WHERE '.$dbh->FULLTEXT_ID_FIELD.'=?', undef, $bug->bug_id);
}
else
{
$bug->_sync_fulltext;
}
# Rollback changes of a SINGLE bug (see process_bug.cgi)
Bugzilla->dbh->bz_rollback_to_savepoint;
$dbh->bz_rollback_to_savepoint;
if (!Bugzilla->request_cache->{checkers_hide_error})
{
show_checker_errors([ $bug ]);

View File

@ -499,6 +499,18 @@ use constant DB_MODULE => {
},
name => 'Oracle',
},
# SQLite 3.6.22 fixes a WHERE clause problem that may affect us.
sqlite => {
db => 'Bugzilla::DB::Sqlite',
db_version => '3.6.22',
dbd => {
package => 'DBD-SQLite',
module => 'DBD::SQLite',
# 1.29 is the version that contains 3.6.22.
version => '1.29',
},
name => 'SQLite',
},
};
# True if we're on Win32.

View File

@ -52,6 +52,8 @@ use Storable qw(dclone);
use constant BLOB_TYPE => DBI::SQL_BLOB;
use constant ISOLATION_LEVEL => 'REPEATABLE READ';
use constant FOR_UPDATE => ' FOR UPDATE';
use constant FULLTEXT_ID_FIELD => 'bug_id';
# Set default values for what used to be the enum types. These values
# are no longer stored in localconfig. If we are upgrading from a
@ -447,13 +449,21 @@ sub sql_fulltext_search
return ($term, $term);
}
sub sql_fulltext_relevance_sum
{
my $self = shift;
my ($bits) = @_;
return "(SELECT ".join("+", @$bits)." FROM bugs_fulltext".
" WHERE bugs_fulltext.".$self->FULLTEXT_ID_FIELD."=bugs.bug_id)";
}
# Prepare string for inserting into full-text table and return the SQL expression
# Individual DB implementations should override this if they have built-in stemmer
sub quote_fulltext
{
my $self = shift;
my ($a) = @_;
return $self->quote(stem_text($a, lc(Bugzilla->params->{stem_language}||'')));
return $self->quote(stem_text(lc $a, lc(Bugzilla->params->{stem_language}||'')));
}
#####################################################################
@ -1161,7 +1171,7 @@ sub bz_start_transaction {
# what we need in Bugzilla to be safe, for what we do.
# Different DBs have different defaults for their isolation
# level, so we just set it here manually.
$self->do('SET TRANSACTION ISOLATION LEVEL ' . $self->ISOLATION_LEVEL);
$self->do('SET TRANSACTION ISOLATION LEVEL ' . $self->ISOLATION_LEVEL) if $self->ISOLATION_LEVEL;
$self->{private_bz_transaction_count} = 1;
}
}

View File

@ -187,7 +187,7 @@ sub sql_fulltext_search
{
my $self = shift;
my ($column, $text) = @_;
$text = $self->quote($text);
$text = $self->quote(lc $text);
my $lang = lc(Bugzilla->params->{stem_language} || 'en');
$lang = LANG_ISO_FULL->{$lang} || 'english' if !LANG_FULL_ISO->{$lang};
# Try to_tsquery, and use plainto_tsquery if the syntax is incorrect
@ -207,7 +207,7 @@ sub quote_fulltext
my ($a) = @_;
my $lang = lc(Bugzilla->params->{stem_language}||'en');
$lang = LANG_ISO_FULL->{$lang} || 'english' if !LANG_FULL_ISO->{$lang};
return "to_tsvector('$lang',".$self->quote($a).")";
return "to_tsvector('$lang',".$self->quote(lc $a).")";
}
sub real_table_list

View File

@ -1781,12 +1781,19 @@ sub _get_create_index_ddl {
my ($self, $table_name, $index_name, $index_fields, $index_type) = @_;
my $sql = "CREATE ";
$sql .= "$index_type " if ($index_type && $index_type eq 'UNIQUE');
$sql .= "INDEX $index_name ON $table_name \(" .
join(", ", @$index_fields) . "\)";
my $fields = join(", ", @$index_fields);
$fields =~ s/\(\d+\)//gso;
return($sql);
if (lc $index_name eq 'primary')
{
return "ALTER TABLE $table_name ADD PRIMARY KEY ($fields)";
}
my $sql = "CREATE ";
$sql .= "$index_type " if $index_type && $index_type eq 'UNIQUE';
$sql .= "INDEX $index_name ON $table_name ($fields)";
return $sql;
} #eosub--_get_create_index_ddl
#--------------------------------------------------------------------------
@ -1855,10 +1862,6 @@ sub get_add_index_ddl {
$index_type = '';
}
if (lc($name) eq 'primary') {
return "ALTER TABLE $table ADD PRIMARY KEY (".join(", ", @$index_fields).")";
}
return $self->_get_create_index_ddl($table, $name, $index_fields,
$index_type);
}

View File

@ -0,0 +1,350 @@
# This Source Code Form is subject to the terms of the Mozilla Public
# License, v. 2.0. If a copy of the MPL was not distributed with this
# file, You can obtain one at http://mozilla.org/MPL/2.0/.
#
# This Source Code Form is "Incompatible With Secondary Licenses", as
# defined by the Mozilla Public License, v. 2.0.
use strict;
package Bugzilla::DB::Schema::Sqlite;
use base qw(Bugzilla::DB::Schema);
use Bugzilla::Error;
use Bugzilla::Util qw(generate_random_password);
use Storable qw(dclone);
use constant FK_ON_CREATE => 1;
sub _initialize
{
my $self = shift;
$self = $self->SUPER::_initialize(@_);
$self->{db_specific} = {
BOOLEAN => 'integer',
FALSE => '0',
TRUE => '1',
INT1 => 'integer',
INT2 => 'integer',
INT3 => 'integer',
INT4 => 'integer',
SMALLSERIAL => 'SERIAL',
MEDIUMSERIAL => 'SERIAL',
INTSERIAL => 'SERIAL',
TINYTEXT => 'text',
MEDIUMTEXT => 'text',
LONGTEXT => 'text',
LONGBLOB => 'blob',
DATETIME => 'DATETIME',
};
$self->_adjust_schema;
return $self;
}
#################################
# General SQLite Schema Helpers #
#################################
sub _sqlite_create_table
{
my ($self, $table) = @_;
return scalar Bugzilla->dbh->selectrow_array(
"SELECT sql FROM sqlite_master WHERE name = ? AND type = 'table'",
undef, $table
);
}
sub _sqlite_create_indexes
{
my ($self, $table) = @_;
return @{$self->{dbh}->selectcol_arrayref(
"SELECT sql FROM sqlite_master WHERE tbl_name = ? AND type = 'index'",
undef, $table
) || []};
}
sub _sqlite_table_lines
{
my $self = shift;
my $table_sql = $self->_sqlite_create_table(@_);
$table_sql =~ s/\n*\)$//s;
# The $ makes this work even if people some day add crazy stuff to their
# schema like multi-column foreign keys.
return split(/,\s*$/m, $table_sql);
}
# This does most of the "heavy lifting" of the schema-altering functions.
sub _sqlite_alter_schema
{
my ($self, $table, $create_table, $options) = @_;
# $create_table is sometimes an array in the form that _sqlite_table_lines returns.
if (ref $create_table)
{
$create_table = join(',', @$create_table) . "\n)";
}
my $dbh = Bugzilla->dbh;
my $random = generate_random_password(5);
my $rename_to = "${table}_$random";
my @columns = $dbh->bz_table_columns_real($table);
push(@columns, $options->{extra_column}) if $options->{extra_column};
if (my $exclude = $options->{exclude_column})
{
@columns = grep { $_ ne $exclude } @columns;
}
my @insert_cols = @columns;
my @select_cols = @columns;
if (my $rename = $options->{rename})
{
foreach my $from (keys %$rename)
{
my $to = $rename->{$from};
@insert_cols = map { $_ eq $from ? $to : $_ } @insert_cols;
}
}
my @indexes = $self->_sqlite_create_indexes($table);
my $insert_str = join(',', @insert_cols);
my $select_str = join(',', @select_cols);
my $copy_sql = "INSERT INTO $table ($insert_str) SELECT $select_str FROM $rename_to";
# We have to turn FKs off before doing this. Otherwise, when we rename
# the table, all of the FKs in the other tables will be automatically
# updated to point to the renamed table. Note that PRAGMA foreign_keys
# can only be set outside of a transaction--otherwise it is a no-op.
if ($dbh->bz_in_transaction)
{
die "can't alter the schema inside of a transaction";
}
my @sql = (
'PRAGMA foreign_keys = OFF',
'BEGIN EXCLUSIVE TRANSACTION',
@{ $options->{pre_sql} || [] },
"ALTER TABLE $table RENAME TO $rename_to",
$create_table,
$copy_sql,
"DROP TABLE $rename_to",
@indexes,
'COMMIT TRANSACTION',
'PRAGMA foreign_keys = ON',
);
return @sql;
}
# For finding a particular column's definition in a CREATE TABLE statement.
sub _sqlite_column_regex
{
my ($column) = @_;
# 1 = Comma at start
# 2 = Column name + Space
# 3 = Definition
# 4 = Ending comma
return qr/(^|,)(\s\Q$column\E\s+)(.*?)(,|$)/m;
}
#############################
# Schema Setup & Alteration #
#############################
sub get_create_database_sql
{
# If we get here, it means there was some error creating the
# database file during bz_create_database in Bugzilla::DB,
# and we just want to display that error instead of doing
# anything else.
Bugzilla->dbh;
die "Reached an unreachable point";
}
sub get_table_ddl
{
my $self = shift;
my ($table) = @_;
if ($table eq 'bugs_fulltext')
{
return 'CREATE VIRTUAL TABLE bugs_fulltext USING fts4'.
' (short_desc, comments, comments_private)';
}
return $self->SUPER::get_table_ddl($table);
}
sub _get_create_table_ddl
{
my $self = shift;
my ($table) = @_;
my $ddl = $self->SUPER::_get_create_table_ddl(@_);
# TheSchwartz uses its own driver to access its tables, meaning
# that it doesn't understand "COLLATE bugzilla" and in fact
# SQLite throws an error when TheSchwartz tries to access its
# own tables, if COLLATE bugzilla is on them. We don't have
# to fix this elsewhere currently, because we only create
# TheSchwartz's tables, we never modify them.
if ($table =~ /^ts_/)
{
$ddl =~ s/ COLLATE bugzilla//g;
}
return $ddl;
}
sub _get_create_index_ddl
{
my $self = shift;
my ($table, $name, $index_fields, $index_type) = @_;
if (lc $name eq 'primary')
{
$name = $table.'_primarykey';
$index_type = 'UNIQUE';
}
return $self->SUPER::_get_create_index_ddl($table, $name, $index_fields, $index_type);
}
sub get_type_ddl
{
my $self = shift;
my $def = dclone($_[0]);
my $ddl = $self->SUPER::get_type_ddl(@_);
if ($def->{PRIMARYKEY} && $def->{TYPE} =~ /SERIAL/i)
{
$ddl =~ s/\bSERIAL\b/integer/;
$ddl =~ s/\bPRIMARY KEY\b/PRIMARY KEY AUTOINCREMENT/;
}
if ($def->{TYPE} =~ /text/i or $def->{TYPE} =~ /char/i)
{
$ddl .= " COLLATE bugzilla";
}
# Don't collate DATETIME fields.
if ($def->{TYPE} eq 'DATETIME')
{
$ddl =~ s/\bDATETIME\b/text COLLATE BINARY/;
}
return $ddl;
}
sub get_alter_column_ddl
{
my $self = shift;
my ($table, $column, $new_def, $set_nulls_to) = @_;
my $dbh = Bugzilla->dbh;
my $table_sql = $self->_sqlite_create_table($table);
my $new_ddl = $self->get_type_ddl($new_def);
# When we do ADD COLUMN, columns can show up all on one line separated
# by commas, so we have to account for that.
my $column_regex = _sqlite_column_regex($column);
$table_sql =~ s/$column_regex/$1$2$new_ddl$4/
|| die "couldn't find $column in $table:\n$table_sql";
my @pre_sql = $self->_set_nulls_sql(@_);
return $self->_sqlite_alter_schema($table, $table_sql, { pre_sql => \@pre_sql });
}
sub get_add_column_ddl
{
my $self = shift;
my ($table, $column, $definition, $init_value) = @_;
# SQLite can use the normal ADD COLUMN when:
# * The column isn't a PK
if ($definition->{PRIMARYKEY})
{
if ($definition->{NOTNULL} && $definition->{TYPE} !~ /SERIAL/i)
{
die "You can only add new SERIAL type PKs with SQLite";
}
my $table_sql = $self->_sqlite_new_column_sql(@_);
# This works because _sqlite_alter_schema will exclude the new column
# in its INSERT ... SELECT statement, meaning that when the "new"
# table is populated, it will have AUTOINCREMENT values generated
# for it.
return $self->_sqlite_alter_schema($table, $table_sql);
}
# * The column has a default one way or another. Either it
# defaults to NULL (it lacks NOT NULL) or it has a DEFAULT
# clause. Since we also require this when doing bz_add_column (in
# the way of forcing an init_value for NOT NULL columns with no
# default), we first set the init_value as the default and then
# alter the column.
if ($definition->{NOTNULL} && !defined $definition->{DEFAULT})
{
my %with_default = %$definition;
$with_default{DEFAULT} = $init_value;
my @pre_sql = $self->SUPER::get_add_column_ddl($table, $column, \%with_default);
my $table_sql = $self->_sqlite_new_column_sql(@_);
return $self->_sqlite_alter_schema(
$table, $table_sql, { pre_sql => \@pre_sql, extra_column => $column }
);
}
return $self->SUPER::get_add_column_ddl(@_);
}
sub _sqlite_new_column_sql
{
my ($self, $table, $column, $def) = @_;
my $table_sql = $self->_sqlite_create_table($table);
my $new_ddl = $self->get_type_ddl($def);
my $new_line = "\t$column\t$new_ddl";
$table_sql =~ s/^(CREATE TABLE \w+ \()/$1\n$new_line,/s
|| die "Can't find start of CREATE TABLE:\n$table_sql";
return $table_sql;
}
sub get_drop_column_ddl
{
my ($self, $table, $column) = @_;
my $table_sql = $self->_sqlite_create_table($table);
my $column_regex = _sqlite_column_regex($column);
$table_sql =~ s/$column_regex/$1/
|| die "Can't find column $column: $table_sql";
# Make sure we don't end up with a comma at the end of the definition.
$table_sql =~ s/,\s+\)$/\n)/s;
return $self->_sqlite_alter_schema($table, $table_sql, { exclude_column => $column });
}
sub get_rename_column_ddl
{
my ($self, $table, $old_name, $new_name) = @_;
my $table_sql = $self->_sqlite_create_table($table);
my $column_regex = _sqlite_column_regex($old_name);
$table_sql =~ s/$column_regex/$1\t$new_name\t$3$4/
|| die "Can't find $old_name: $table_sql";
my %rename = ($old_name => $new_name);
return $self->_sqlite_alter_schema($table, $table_sql, { rename => \%rename });
}
################
# Foreign Keys #
################
sub get_add_fk_sql
{
my ($self, $table, $column, $def) = @_;
my @clauses = $self->_sqlite_table_lines($table);
my @add = $self->get_fk_ddl($table, $column, $def);
push(@clauses, @add);
return $self->_sqlite_alter_schema($table, \@clauses);
}
sub get_drop_fk_sql
{
my ($self, $table, $column, $references) = @_;
my @clauses = $self->_sqlite_table_lines($table);
my $fk_name = $self->_get_fk_name($table, $column, $references);
my $line_re = qr/^\s+CONSTRAINT $fk_name /s;
grep { $line_re } @clauses or die "Can't find $fk_name: " . join(',', @clauses);
@clauses = grep { $_ !~ $line_re } @clauses;
return $self->_sqlite_alter_schema($table, \@clauses);
}
1;

366
Bugzilla/DB/Sqlite.pm Normal file
View File

@ -0,0 +1,366 @@
# This Source Code Form is subject to the terms of the Mozilla Public
# License, v. 2.0. If a copy of the MPL was not distributed with this
# file, You can obtain one at http://mozilla.org/MPL/2.0/.
#
# This Source Code Form is "Incompatible With Secondary Licenses", as
# defined by the Mozilla Public License, v. 2.0.
use strict;
package Bugzilla::DB::Sqlite;
use base qw(Bugzilla::DB);
use Bugzilla::Constants;
use Bugzilla::Error;
use Bugzilla::Util;
use Bugzilla::Install::Util qw(install_string);
use DateTime;
use POSIX ();
# SQLite only supports the SERIALIZABLE and READ UNCOMMITTED isolation
# levels. SERIALIZABLE is used by default and SET TRANSACTION ISOLATION
# LEVEL is not implemented.
use constant ISOLATION_LEVEL => undef;
use constant FOR_UPDATE => '';
use constant FULLTEXT_ID_FIELD => 'docid';
# Since we're literally using Perl's regexes, we can use something
# simpler and more efficient than what Bugzilla::DB uses.
use constant WORD_START => '(?:^|\W)';
use constant WORD_END => '(?:$|\W)';
# For some reason, dropping the related FKs causes the index to
# disappear early, which causes all sorts of problems.
use constant INDEX_DROPS_REQUIRE_FK_DROPS => 0;
####################################
# Functions Added To SQLite Itself #
####################################
# A case-insensitive, Unicode collation for SQLite. This allows us to
# make all comparisons and sorts case-insensitive (though unfortunately
# not accent-insensitive).
sub _sqlite_collate_ci { lc($_[0]) cmp lc($_[1]) }
sub _sqlite_mod { $_[0] % $_[1] }
sub _sqlite_now
{
my $now = DateTime->now(time_zone => Bugzilla->local_timezone);
return $now->ymd . ' ' . $now->hms;
}
# SQL's POSITION starts its values from 1 instead of 0 (so we add 1).
sub _sqlite_position
{
my ($text, $fragment) = @_;
if (!defined $text or !defined $fragment)
{
return undef;
}
my $pos = index $text, $fragment;
return $pos + 1;
}
sub _sqlite_position_ci
{
my ($text, $fragment) = @_;
if (!defined $text or !defined $fragment)
{
return undef;
}
my $pos = index lc($text), lc($fragment);
return $pos + 1;
}
# BM25 ranking for SQLite FTS4 fulltext search
# Usage: bm25(matchinfo(table, 'pcnalx'), search_column_number)
sub _sqlite_bm25
{
my ($matchinfo, $searchTextCol, $K1, $B) = @_;
$K1 ||= 1.2;
$B ||= 0.75;
$matchinfo = [ unpack('V*', $matchinfo) ];
my $termCount = $matchinfo->[0];
my $colCount = $matchinfo->[1];
my $totalDocs = $matchinfo->[2];
$searchTextCol = $colCount-1 if $searchTextCol >= $colCount;
$searchTextCol = 0 if $searchTextCol < 0;
my $avgLength = $matchinfo->[3 + $searchTextCol];
my $docLength = $matchinfo->[3 + $colCount + $searchTextCol];
my $sum = 0;
for (my $i = 0; $i < $termCount; $i++)
{
my $termFreq = $matchinfo->[3 + 2*$colCount + 3*($i*$colCount + $searchTextCol)];
my $docsWithTerm = $matchinfo->[3 + 2*$colCount + 3*($i*$colCount + $searchTextCol) + 2];
my $idf = log(($totalDocs - $docsWithTerm + 0.5) / ($docsWithTerm + 0.5));
my $rightSide = ($termFreq * ($K1+1)) / ($termFreq + $K1*(1 - $B + $B*$docLength/$avgLength));
$sum += $idf * $rightSide if $idf > 0;
}
return $sum;
}
###############
# Constructor #
###############
sub new
{
my ($class, $user, $pass, $host, $db_name, $port, $sock) = @_;
# Let people specify paths intead of data/ for the DB.
if ($db_name and $db_name !~ m{[\\/]})
{
# When the DB is first created, there's a chance that the
# data directory doesn't exist at all, because the Install::Filesystem
# code happens after DB creation. So we create the directory ourselves
# if it doesn't exist.
my $datadir = bz_locations()->{datadir};
if (!-d $datadir)
{
mkdir $datadir or warn "$datadir: $!";
}
if (!-d "$datadir/db/")
{
mkdir "$datadir/db/" or warn "$datadir/db: $!";
}
$db_name = bz_locations()->{datadir} . "/db/$db_name";
}
# construct the DSN from the parameters we got
my $dsn = "dbi:SQLite:dbname=$db_name";
my $attrs = {
# FIXME Should we just enforce this to be always on?
sqlite_unicode => Bugzilla->params->{utf8},
};
my $self = $class->db_new($dsn, '', '', $attrs);
# Needed by TheSchwartz
$self->{private_bz_dsn} = $dsn;
my %pragmas = (
# Make sure that the sqlite file doesn't grow without bound.
auto_vacuum => 1,
encoding => "'UTF-8'",
foreign_keys => 'ON',
# We want the latest file format.
legacy_file_format => 'OFF',
# This guarantees that we get column names like "foo"
# instead of "table.foo" in selectrow_hashref.
short_column_names => 'ON',
# The write-ahead log mode in SQLite 3.7 gets us better concurrency,
# but breaks backwards-compatibility with older versions of
# SQLite. (Which is important because people may also want to use
# command-line clients to access and back up their DB.) If you need
# better concurrency and don't need 3.6 compatibility, then you can
# uncomment this line.
journal_mode => "'WAL'",
);
while (my ($name, $value) = each %pragmas)
{
$self->do("PRAGMA $name = $value");
}
$self->sqlite_create_collation('bugzilla', \&_sqlite_collate_ci);
$self->sqlite_create_function('position', 2, \&_sqlite_position);
$self->sqlite_create_function('iposition', 2, \&_sqlite_position_ci);
# SQLite has a "substr" function, but other DBs call it "SUBSTRING"
# so that's what we use, and I don't know of any way in SQLite to
# alias the SQL "substr" function to be called "SUBSTRING".
$self->sqlite_create_function('substring', 3, \&CORE::substr);
$self->sqlite_create_function('char_length', 1, sub { length($_[0]) });
$self->sqlite_create_function('mod', 2, \&_sqlite_mod);
$self->sqlite_create_function('now', 0, \&_sqlite_now);
$self->sqlite_create_function('localtimestamp', 1, \&_sqlite_now);
$self->sqlite_create_function('floor', 1, \&POSIX::floor);
$self->sqlite_create_function('bm25', 4, \&_sqlite_bm25);
bless ($self, $class);
return $self;
}
###############
# SQL Methods #
###############
sub sql_position
{
my ($self, $fragment, $text) = @_;
return "POSITION($text, $fragment)";
}
sub sql_iposition
{
my ($self, $fragment, $text) = @_;
return "IPOSITION($text, $fragment)";
}
# SQLite does not have to GROUP BY the optional columns.
sub sql_group_by
{
my ($self, $needed_columns, $optional_columns) = @_;
my $expression = "GROUP BY $needed_columns";
return $expression;
}
# FIXME SQLite does not support sorting a GROUP_CONCAT, so $sort is unimplemented.
sub sql_group_concat
{
my ($self, $column, $separator, $sort) = @_;
$separator = $self->quote(', ') if !defined $separator;
# In SQLite, a GROUP_CONCAT call with a DISTINCT argument can't
# specify its separator, and has to accept the default of ",".
if ($column =~ /^DISTINCT/)
{
return "GROUP_CONCAT($column)";
}
return "GROUP_CONCAT($column, $separator)";
}
sub sql_istring
{
my ($self, $string) = @_;
return $string;
}
sub sql_regexp
{
my ($self, $expr, $pattern, $nocheck, $real_pattern) = @_;
$real_pattern ||= $pattern;
$self->bz_check_regexp($real_pattern) if !$nocheck;
return "$expr REGEXP $pattern";
}
sub sql_not_regexp
{
my $self = shift;
my $re_expression = $self->sql_regexp(@_);
return "NOT($re_expression)";
}
sub sql_limit
{
my ($self, $limit, $offset) = @_;
if (defined($offset))
{
return "LIMIT $limit OFFSET $offset";
}
else
{
return "LIMIT $limit";
}
}
sub sql_from_days
{
my ($self, $days) = @_;
return "DATETIME($days)";
}
sub sql_to_days
{
my ($self, $date) = @_;
return "JULIANDAY($date)";
}
sub sql_date_format
{
my ($self, $date, $format) = @_;
$format = "%Y.%m.%d %H:%M:%S" if !$format;
$format =~ s/\%i/\%M/g;
return "STRFTIME(" . $self->quote($format) . ", $date)";
}
sub sql_date_math
{
my ($self, $date, $operator, $interval, $units) = @_;
# We do the || thing (concatenation) so that placeholders work properly.
return "DATETIME($date, '$operator' || $interval || ' $units')";
}
# Fulltext search using SQLite
sub sql_fulltext_search
{
my $self = shift;
my ($column, $text) = @_;
$text = $self->quote_fulltext($text);
my $ncol = $column;
$ncol =~ s/^.*\.//so;
$ncol = { short_desc => 0, comments => 1, comments_private => 2 } -> { lc $ncol };
return ("$column MATCH $text", "COALESCE((SELECT bm25(matchinfo(bugs_fulltext, 'pcnalx'), $ncol, 1.2, 0.75)".
" FROM bugs_fulltext WHERE docid=bugs.bug_id AND $column MATCH $text), 0)");
}
sub sql_fulltext_relevance_sum
{
my $self = shift;
my ($bits) = @_;
return "(".join("+", @$bits).")";
}
sub bz_explain
{
my $self = shift;
my ($sql) = @_;
my $rows = $self->selectall_arrayref("EXPLAIN QUERY PLAN $sql");
my @seq;
my $subq = [];
foreach my $row (@$rows)
{
if (!$subq->[$row->[0]])
{
$subq->[$row->[0]] = "Subquery ".$row->[0]."\n";
push @seq, $row->[0];
}
$subq->[$row->[0]] .= " ".(" " x $row->[1]).$row->[3]."\n";
}
return join '', @$subq[@seq];
}
sub bz_table_list_real
{
my $self = shift;
my @tables = $self->SUPER::bz_table_list_real(@_);
# SQLite includes a sqlite_sequence table in every database that isn't
# one of our real tables. We exclude any table that starts with sqlite_,
# just to be safe.
@tables = grep { $_ !~ /^sqlite_/ } @tables;
return @tables;
}
sub bz_add_fk
{
my $self = shift;
my ($table, $column, $def) = @_;
return if $table eq 'bugs_fulltext';
$self->SUPER::bz_add_fk(@_);
}
sub bz_setup_foreign_keys
{
my $self = shift;
$self->SUPER::bz_setup_foreign_keys();
print "Running ANALYZE to rebuild statistics for all tables\n";
$self->do("ANALYZE main");
}
1;
__END__
=head1 NAME
Bugzilla::DB::Sqlite - Bugzilla database compatibility layer for SQLite
=head1 DESCRIPTION
This module overrides methods of the Bugzilla::DB module with a
SQLite-specific implementation. It is instantiated by the Bugzilla::DB module
and should never be used directly.
For interface details see L<Bugzilla::DB> and L<DBI>.

View File

@ -3425,7 +3425,7 @@ sub _populate_bugs_fulltext
$bug_ids = undef if $bug_ids && !@$bug_ids;
my $dbh = Bugzilla->dbh;
# These vary between different fulltext search engines (MySQL, Sphinx)
my ($table, $id_field, $quote, $sph) = ('bugs_fulltext', 'bug_id', 'quote_fulltext', $dbh);
my ($table, $id_field, $quote, $sph) = ('bugs_fulltext', $dbh->FULLTEXT_ID_FIELD, 'quote_fulltext', $dbh);
my $nonempty;
if (Bugzilla->localconfig->{sphinx_index})
{

View File

@ -137,6 +137,7 @@ sub FILESYSTEM
$attachdir => { files => $ws_writeable, dirs => $ws_dir_writeable },
$webdotdir => { files => $ws_writeable, dirs => $ws_dir_writeable },
$graphsdir => { files => $ws_writeable, dirs => $ws_dir_writeable },
"$datadir/db" => { files => $ws_writeable, dirs => $ws_dir_writeable },
# Readable directories
"$datadir/mining" => { files => $ws_readable, dirs => $ws_dir_readable },

View File

@ -594,6 +594,10 @@ sub have_vers {
if ($module eq 'CPAN' and $vnum =~ /^(\d\.\d{2})\d{2}$/) {
$vnum = $1;
}
# Debian has Image::Magick without version
if ($module eq 'Image::Magick' && (my ($isa) = @Image::Magick::ISA) && $vnum == -1) {
$vnum = $isa->VERSION || -1;
}
my $vstr;
if ($vnum eq "-1") { # string compare just in case it's non-numeric

View File

@ -774,7 +774,7 @@ sub insert_bugs {
# bugs_fulltext isn't transactional, so if we're in a dry-run we
# need to delete anything that we put in there.
if ($self->dry_run) {
$dbh->do('DELETE FROM bugs_fulltext WHERE bug_id = ?',
$dbh->do('DELETE FROM bugs_fulltext WHERE '.$dbh->FULLTEXT_ID_FIELD.' = ?',
undef, $created->id);
}

View File

@ -118,7 +118,7 @@ sub _init
$sql = "SELECT $columns FROM $table WHERE $sql";
if (ref $param eq 'HASH' && $param->{for_update})
{
$sql .= " FOR UPDATE";
$sql .= $dbh->FOR_UPDATE;
}
$object = $dbh->selectrow_hashref($sql, undef, @values);

View File

@ -2396,7 +2396,9 @@ sub _content_matches
# MATCH(...) OR MATCH(...) is very slow in MySQL (and probably in other DBs):
# -- it does no fulltext index merge optimization. So use JOIN to UNION.
$self->{term} = {
table => "(".join(" UNION ", map { "SELECT bug_id FROM bugs_fulltext WHERE $terms[$_]" } grep { !($_&1) } 0..$#terms).") $table",
table => "(".join(" UNION ", map {
"SELECT ".$dbh->FULLTEXT_ID_FIELD." bug_id FROM bugs_fulltext WHERE $terms[$_]"
} grep { !($_&1) } 0..$#terms).") $table",
bugid_field => "$table.bug_id",
};
@ -2409,8 +2411,7 @@ sub _content_matches
if (!$self->{negated})
{
push @{COLUMNS->{relevance}->{bits}}, @terms[grep { $_&1 } 0..$#terms];
COLUMNS->{relevance}->{name} = "(SELECT ".join("+", @{COLUMNS->{relevance}->{bits}}).
" FROM bugs_fulltext WHERE bugs_fulltext.bug_id=bugs.bug_id)";
COLUMNS->{relevance}->{name} = $dbh->sql_fulltext_relevance_sum(COLUMNS->{relevance}->{bits});
}
}
@ -3476,7 +3477,7 @@ sub expression_sql_or
$q[$i] = $self->expression_sql_and(ref $q[$i] eq 'ARRAY' ? $q[$i] : [ 'AND', $q[$i] ]);
}
my $r = {
table => "((".join(")\nUNION (", @q).")) u".$self->{sequence},
table => "(".join("\nUNION\n", @q).") u".$self->{sequence},
bugid_field => "u$self->{sequence}.bug_id",
};
$self->{sequence}++;

View File

@ -821,15 +821,16 @@ sub get_selectable_products
else
{
my $query =
"(SELECT id, name AS pname FROM products" .
"SELECT id, name AS pname FROM products" .
" LEFT JOIN group_control_map g ON g.product_id = products.id " .
" AND g.membercontrol=" . CONTROLMAPMANDATORY .
" AND g.group_id NOT IN (" . $self->groups_as_string . ")" .
" WHERE group_id IS NULL)" .
" UNION (SELECT id, name AS pname FROM products" .
" WHERE group_id IS NULL" .
" UNION ".
" SELECT id, name AS pname FROM products" .
" LEFT JOIN group_control_map g ON g.product_id=products.id" .
" AND g.entry != 0 AND g.group_id NOT IN (".$self->groups_as_string.")" .
" WHERE g.group_id IS NULL)" .
" WHERE g.group_id IS NULL" .
" ORDER BY pname";
$prod_ids = Bugzilla->dbh->selectcol_arrayref($query);
}

View File

@ -22,6 +22,12 @@ Backports from original Bugzilla 4.4:
to Bugzilla4Intranet.
* Allow to disable old versions/milestones.
* Saved reports.
* SQLite support, in fact improved over original 4.4:
** It's possible to use built-in SQLite full-text search (FTS4)
** Query plans are shown when &debug=1 parameter is passed to buglist.cgi
** It's possible to use contrib/bzdbcopy.pl script with SQLite
** Bugfix: indexes are not deleted anymore when altering tables
** ANALYZE is run in the end of checksetup.pl
* Add user "last seen date".
Bug field improvements:

View File

@ -129,7 +129,7 @@ if ($query)
$sqlquery = $search->bugid_query;
}
$sqlquery = " UNION ($sqlquery)" if $sqlquery;
$sqlquery = " UNION $sqlquery" if $sqlquery;
my $tm = $dbh->sql_date_math('CURRENT_DATE', '-', $lastdays-1, 'DAY');
my $join = $dbh->isa('Bugzilla::DB::Mysql') ? 'STRAIGHT_JOIN' : 'JOIN';