[DATABASE][PostgreSQL] Add fulltext search support

This commit is contained in:
Alexei Sorokin 2020-08-08 16:56:20 +03:00
parent b20c0bdec7
commit 34ec165bff
2 changed files with 51 additions and 4 deletions

View File

@ -152,6 +152,15 @@ class PgsqlSchema extends Schema
case 'unique': case 'unique':
$def['unique keys'][$key_name] = $cols; $def['unique keys'][$key_name] = $cols;
break; break;
case 'gin':
// @fixme Way too magical.
$cols = array_values(preg_grep(
'/^(.+(\(|\)).+|\s*)$/',
preg_split('(COALESCE\(|,)', $cols[0]),
PREG_GREP_INVERT
));
$def['fulltext indexes'][$key_name] = $cols;
break;
default: default:
$def['indexes'][$key_name] = $cols; $def['indexes'][$key_name] = $cols;
} }
@ -211,7 +220,12 @@ class PgsqlSchema extends Schema
WHEN "idx"."indisunique" IS TRUE THEN 'unique' WHEN "idx"."indisunique" IS TRUE THEN 'unique'
ELSE "am"."amname" ELSE "am"."amname"
END AS "key_type", END AS "key_type",
"cols"."attname" AS "col" CASE
WHEN "cols"."attname" IS NOT NULL THEN "cols"."attname"
ELSE pg_get_indexdef("idx"."indexrelid",
CAST("col_nums"."pos" AS INTEGER),
TRUE)
END AS "col"
FROM pg_index AS "idx" FROM pg_index AS "idx"
CROSS JOIN LATERAL unnest("idx"."indkey") CROSS JOIN LATERAL unnest("idx"."indkey")
WITH ORDINALITY AS "col_nums" ("num", "pos") WITH ORDINALITY AS "col_nums" ("num", "pos")
@ -377,6 +391,24 @@ class PgsqlSchema extends Schema
$phrase[] = 'DROP CONSTRAINT ' . $this->quoteIdentifier($tableName . '_pkey'); $phrase[] = 'DROP CONSTRAINT ' . $this->quoteIdentifier($tableName . '_pkey');
} }
public function buildFulltextIndexList($table, array $def)
{
foreach ($def as &$val) {
$cols[] = $this->buildFulltextIndexItem($table, $val);
}
return "(to_tsvector('english', " . implode(" || ' ' || ", $cols) . '))';
}
public function buildFulltextIndexItem($table, $def)
{
return sprintf(
"COALESCE(%s.%s, '')",
$this->quoteIdentifier($table),
$def
);
}
public function mapType($column) public function mapType($column)
{ {
$map = [ $map = [
@ -407,6 +439,21 @@ class PgsqlSchema extends Schema
return $type; return $type;
} }
/**
* Append an SQL statement with an index definition for a full-text search
* index over one or more columns on a table.
*
* @param array $statements
* @param string $table
* @param string $name
* @param array $def
*/
public function appendCreateFulltextIndex(array &$statements, $table, $name, array $def)
{
$statements[] = "CREATE INDEX {$name} ON {$table} USING gin "
. $this->buildFulltextIndexList($table, $def);
}
/** /**
* Filter the given table definition array to match features available * Filter the given table definition array to match features available
* in this database. * in this database.

View File

@ -78,7 +78,7 @@ class PostgreSQLSearch extends SearchEngine
$cols = implode(" || ' ' || ", array_map( $cols = implode(" || ' ' || ", array_map(
function ($col) { function ($col) {
return sprintf( return sprintf(
"COALESCE(%s.%s, '')", 'COALESCE(%s."%s", \'\')',
common_database_tablename($this->table), common_database_tablename($this->table),
$col $col
); );
@ -87,7 +87,7 @@ class PostgreSQLSearch extends SearchEngine
)); ));
$this->target->whereAdd(sprintf( $this->target->whereAdd(sprintf(
'to_tsvector(\'english\', %2$s) @@ plainto_tsquery(\'%1$s\')', 'to_tsvector(\'english\', %2$s) @@ websearch_to_tsquery(\'%1$s\')',
$this->target->escape($q, true), $this->target->escape($q, true),
$cols $cols
)); ));
@ -97,7 +97,7 @@ class PostgreSQLSearch extends SearchEngine
$this->target->whereAdd('notice.is_local <> ' . Notice::GATEWAY); $this->target->whereAdd('notice.is_local <> ' . Notice::GATEWAY);
$this->target->whereAdd(sprintf( $this->target->whereAdd(sprintf(
'to_tsvector(\'english\', content) @@ plainto_tsquery(\'%1$s\')', 'to_tsvector(\'english\', "content") @@ websearch_to_tsquery(\'%1$s\')',
$this->target->escape($q, true) $this->target->escape($q, true)
)); ));
return true; return true;