aboutsummaryrefslogtreecommitdiffstats
path: root/db
diff options
context:
space:
mode:
Diffstat (limited to 'db')
-rw-r--r--db/downgrade_0073---0072.sql2
-rw-r--r--db/downgrade_0074---0073.sql1
-rw-r--r--db/schema.sql18
-rw-r--r--db/schema_0073-add-full-text-search-index.sql13
-rw-r--r--db/schema_0074-add-users-full-text-search-index.sql6
5 files changed, 40 insertions, 0 deletions
diff --git a/db/downgrade_0073---0072.sql b/db/downgrade_0073---0072.sql
new file mode 100644
index 000000000..1ae19b9d7
--- /dev/null
+++ b/db/downgrade_0073---0072.sql
@@ -0,0 +1,2 @@
+DROP INDEX problem_fulltext_idx;
+DROP INDEX comment_fulltext_idx;
diff --git a/db/downgrade_0074---0073.sql b/db/downgrade_0074---0073.sql
new file mode 100644
index 000000000..f900cc1d7
--- /dev/null
+++ b/db/downgrade_0074---0073.sql
@@ -0,0 +1 @@
+DROP INDEX users_fulltext_idx;
diff --git a/db/schema.sql b/db/schema.sql
index ed21aded6..2c0cedb8d 100644
--- a/db/schema.sql
+++ b/db/schema.sql
@@ -41,6 +41,12 @@ create table users (
);
CREATE UNIQUE INDEX users_email_verified_unique ON users (email) WHERE email_verified;
CREATE UNIQUE INDEX users_phone_verified_unique ON users (phone) WHERE phone_verified;
+create index users_fulltext_idx on users USING GIN(
+ to_tsvector(
+ 'english',
+ translate(id || ' ' || coalesce(name,'') || ' ' || coalesce(email,'') || ' ' || coalesce(phone,''), '@.', ' ')
+ )
+);
-- Record details of reporting bodies, including open311 configuration details
create table body (
@@ -246,6 +252,12 @@ create index problem_user_id_idx on problem ( user_id );
create index problem_external_body_idx on problem(lower(external_body));
create index problem_radians_latitude_longitude_idx on problem(radians(latitude), radians(longitude));
create index problem_bodies_str_array_idx on problem USING gin(regexp_split_to_array(bodies_str, ','));
+create index problem_fulltext_idx on problem USING GIN(
+ to_tsvector(
+ 'english',
+ translate(id || ' ' || coalesce(external_id,'') || ' ' || coalesce(bodies_str,'') || ' ' || name || ' ' || title || ' ' || detail, '/.', ' ')
+ )
+);
create table questionnaire (
id serial not null primary key,
@@ -354,6 +366,12 @@ create table comment (
create index comment_user_id_idx on comment(user_id);
create index comment_problem_id_idx on comment(problem_id);
create index comment_problem_id_created_idx on comment(problem_id, created);
+create index comment_fulltext_idx on comment USING GIN(
+ to_tsvector(
+ 'english',
+ translate(id || ' ' || problem_id || ' ' || coalesce(name,'') || ' ' || text, '/.', ' ')
+ )
+);
-- Tokens for confirmations
create table token (
diff --git a/db/schema_0073-add-full-text-search-index.sql b/db/schema_0073-add-full-text-search-index.sql
new file mode 100644
index 000000000..9871386bd
--- /dev/null
+++ b/db/schema_0073-add-full-text-search-index.sql
@@ -0,0 +1,13 @@
+CREATE INDEX CONCURRENTLY problem_fulltext_idx ON problem USING GIN(
+ to_tsvector(
+ 'DB_FULL_TEXT_SEARCH_CONFIG',
+ translate(id || ' ' || coalesce(external_id,'') || ' ' || coalesce(bodies_str,'') || ' ' || name || ' ' || title || ' ' || detail, '/.', ' ')
+ )
+);
+
+CREATE INDEX CONCURRENTLY comment_fulltext_idx on comment USING GIN(
+ to_tsvector(
+ 'DB_FULL_TEXT_SEARCH_CONFIG',
+ translate(id || ' ' || problem_id || ' ' || coalesce(name,'') || ' ' || text, '/.', ' ')
+ )
+);
diff --git a/db/schema_0074-add-users-full-text-search-index.sql b/db/schema_0074-add-users-full-text-search-index.sql
new file mode 100644
index 000000000..dc743bd47
--- /dev/null
+++ b/db/schema_0074-add-users-full-text-search-index.sql
@@ -0,0 +1,6 @@
+CREATE INDEX CONCURRENTLY users_fulltext_idx on users USING GIN(
+ to_tsvector(
+ 'DB_FULL_TEXT_SEARCH_CONFIG',
+ translate(id || ' ' || coalesce(name,'') || ' ' || coalesce(email,'') || ' ' || coalesce(phone,''), '@.', ' ')
+ )
+);