From 0ea69cfc3ed143b138ef38383c444bc4a9ee7e32 Mon Sep 17 00:00:00 2001 From: Julien Portalier Date: Tue, 25 Oct 2016 18:45:05 +0200 Subject: [PATCH] PostgreSQL full text search [WIP] --- Gemfile | 2 + Gemfile.lock | 7 ++ .../backoffice/dossiers_controller.rb | 10 ++- app/models/search.rb | 39 +++++++++++ db/migrate/20161025150900_create_searches.rb | 68 +++++++++++++++++++ db/schema.rb | 44 +++++++++++- db/views/searches_v01.sql | 57 ++++++++++++++++ spec/models/search_spec.rb | 5 ++ 8 files changed, 230 insertions(+), 2 deletions(-) create mode 100644 app/models/search.rb create mode 100644 db/migrate/20161025150900_create_searches.rb create mode 100644 db/views/searches_v01.sql create mode 100644 spec/models/search_spec.rb diff --git a/Gemfile b/Gemfile index 026ba7955..ba68e79a7 100644 --- a/Gemfile +++ b/Gemfile @@ -62,6 +62,8 @@ gem 'fog' gem 'fog-openstack' gem 'pg' +gem 'scenic' +gem 'textacular' gem 'rgeo-geojson' gem 'leaflet-rails' diff --git a/Gemfile.lock b/Gemfile.lock index a7599faa6..f85d05b05 100644 --- a/Gemfile.lock +++ b/Gemfile.lock @@ -516,6 +516,9 @@ GEM sprockets (>= 2.8, < 4.0) sprockets-rails (>= 2.0, < 4.0) tilt (>= 1.1, < 3) + scenic (1.3.0) + activerecord (>= 4.0.0) + railties (>= 4.0.0) sdoc (0.4.1) json (~> 1.7, >= 1.7.7) rdoc (~> 4.0) @@ -563,6 +566,8 @@ GEM json (>= 1.4.3) temple (0.7.6) terminal-table (1.5.2) + textacular (4.0.1) + activerecord (>= 3.0, < 5.1) therubyracer (0.12.2) libv8 (~> 3.16.14.0) ref @@ -673,6 +678,7 @@ DEPENDENCIES rubocop-checkstyle_formatter rubocop-rspec sass-rails (~> 5.0) + scenic sdoc (~> 0.4.0) selenium-webdriver sentry-raven @@ -681,6 +687,7 @@ DEPENDENCIES smart_listing spring spring-commands-rspec + textacular therubyracer timecop turbolinks diff --git a/app/controllers/backoffice/dossiers_controller.rb b/app/controllers/backoffice/dossiers_controller.rb index 9c4895798..d4b1d4089 100644 --- a/app/controllers/backoffice/dossiers_controller.rb +++ b/app/controllers/backoffice/dossiers_controller.rb @@ -27,7 +27,15 @@ class Backoffice::DossiersController < Backoffice::DossiersListController def search @search_terms = params[:q] - @dossier = Dossier.search(current_gestionnaire, @search_terms) + + @dossier = Search.new( + gestionnaire: current_gestionnaire, + query: @search_terms, + ).results + + unless @dossier.empty? + @dossiers = @dossiers.paginate(page: params[:page]) + end smartlisting_dossier @dossier, 'search' diff --git a/app/models/search.rb b/app/models/search.rb new file mode 100644 index 000000000..2380a33b6 --- /dev/null +++ b/app/models/search.rb @@ -0,0 +1,39 @@ +# See: +# - https://robots.thoughtbot.com/implementing-multi-table-full-text-search-with-postgres +# - http://calebthompson.io/talks/search.html +class Search < ActiveRecord::Base + extend Textacular + + attr_accessor :gestionnaire + attr_accessor :query + + belongs_to :dossier + + def results + if @query.present? + self.class + .select("DISTINCT(dossiers.*)") + .search(@query) + .joins(:dossier) + .where(dossier_id: @gestionnaire.dossier_ids) + .where("dossiers.archived = ? AND dossiers.state != ?", false, "draft") + .map(&:dossier) + else + Search.none + end + end + + def self.searchable_language + "french" + end + + def self.searchable_columns + %i(term) + end + + # NOTE: could be executed concurrently + # See https://github.com/thoughtbot/scenic#what-about-materialized-views + def self.refresh + Scenic.database.refresh_materialized_view(table_name, concurrently: false) + end +end diff --git a/db/migrate/20161025150900_create_searches.rb b/db/migrate/20161025150900_create_searches.rb new file mode 100644 index 000000000..017892474 --- /dev/null +++ b/db/migrate/20161025150900_create_searches.rb @@ -0,0 +1,68 @@ +class CreateSearches < ActiveRecord::Migration + def up + create_view :searches, materialized: true + + matrix.each do |table, fields| + fields.each do |field| + execute "CREATE INDEX tsv_index_#{table}_on_#{field} ON #{table} USING GIN(to_tsvector('french', #{field}))" + end + end + end + + def down + drop_view :searches + + matrix.each do |table, fields| + fields.each do |field| + execute "DROP INDEX IF EXISTS tsv_index_#{table}_on_#{field}" + end + end + end + + def matrix + { + cerfas: %i( + content + ), + champs: %i( + value + ), + entreprises: %i( + siren + numero_tva_intracommunautaire + forme_juridique + forme_juridique_code + nom_commercial + raison_sociale + siret_siege_social + nom + prenom + ), + rna_informations: %i( + association_id + titre + objet + ), + etablissements: %i( + siret + naf + libelle_naf + adresse + code_postal + localite + code_insee_localite + ), + individuals: %i( + nom + prenom + ), + pieces_justificatives: %i( + content + ), + france_connect_informations: %i( + given_name + family_name + ), + } + end +end diff --git a/db/schema.rb b/db/schema.rb index 17762a2b4..126477bd2 100644 --- a/db/schema.rb +++ b/db/schema.rb @@ -11,7 +11,7 @@ # # It's strongly recommended that you check this file into your version control system. -ActiveRecord::Schema.define(version: 20161011125345) do +ActiveRecord::Schema.define(version: 20161025150900) do # These are extensions that must be enabled in order to support this database enable_extension "plpgsql" @@ -369,4 +369,46 @@ ActiveRecord::Schema.define(version: 20161011125345) do add_foreign_key "dossiers", "users" add_foreign_key "procedure_paths", "administrateurs" add_foreign_key "procedure_paths", "procedures" + + create_view :searches, sql_definition: <<-SQL + SELECT dossiers.id AS dossier_id, + (dossiers.id)::text AS term + FROM dossiers + UNION + SELECT cerfas.dossier_id, + cerfas.content AS term + FROM cerfas + UNION + SELECT champs.dossier_id, + champs.value AS term + FROM champs + UNION + SELECT champs.dossier_id, + drop_down_lists.value AS term + FROM (drop_down_lists + JOIN champs ON ((champs.type_de_champ_id = champs.type_de_champ_id))) + UNION + SELECT entreprises.dossier_id, + (((((((((((((((((((((((entreprises.siren)::text || ' '::text) || (entreprises.numero_tva_intracommunautaire)::text) || ' '::text) || (entreprises.forme_juridique)::text) || ' '::text) || (entreprises.forme_juridique_code)::text) || ' '::text) || (entreprises.nom_commercial)::text) || ' '::text) || (entreprises.raison_sociale)::text) || ' '::text) || (entreprises.siret_siege_social)::text) || ' '::text) || (entreprises.nom)::text) || ' '::text) || (entreprises.prenom)::text) || ' '::text) || (rna_informations.association_id)::text) || ' '::text) || (rna_informations.titre)::text) || ' '::text) || rna_informations.objet) AS term + FROM (entreprises + JOIN rna_informations ON ((rna_informations.entreprise_id = entreprises.id))) + UNION + SELECT etablissements.dossier_id, + (((((((((((((etablissements.siret)::text || ' '::text) || (etablissements.naf)::text) || ' '::text) || (etablissements.libelle_naf)::text) || ' '::text) || (etablissements.adresse)::text) || ' '::text) || (etablissements.code_postal)::text) || ' '::text) || (etablissements.localite)::text) || ' '::text) || (etablissements.code_insee_localite)::text) AS term + FROM etablissements + UNION + SELECT individuals.dossier_id, + (((individuals.nom)::text || ' '::text) || (individuals.prenom)::text) AS term + FROM individuals + UNION + SELECT pieces_justificatives.dossier_id, + pieces_justificatives.content AS term + FROM pieces_justificatives + UNION + SELECT dossiers.id AS dossier_id, + (((france_connect_informations.given_name)::text || ' '::text) || (france_connect_informations.family_name)::text) AS term + FROM (france_connect_informations + JOIN dossiers ON ((dossiers.user_id = france_connect_informations.user_id))); + SQL + end diff --git a/db/views/searches_v01.sql b/db/views/searches_v01.sql new file mode 100644 index 000000000..cd37c0d71 --- /dev/null +++ b/db/views/searches_v01.sql @@ -0,0 +1,57 @@ +SELECT dossiers.id AS dossier_id, + dossiers.id::text AS term + FROM dossiers + +UNION SELECT cerfas.dossier_id, + cerfas.content AS term + FROM cerfas + +UNION SELECT champs.dossier_id, + champs.value AS term + FROM champs + +UNION SELECT champs.dossier_id, + drop_down_lists.value AS term + FROM drop_down_lists + INNER JOIN champs ON champs.type_de_champ_id = champs.type_de_champ_id + +UNION SELECT entreprises.dossier_id, + entreprises.siren || ' ' || + entreprises.numero_tva_intracommunautaire || ' ' || + entreprises.forme_juridique || ' ' || + entreprises.forme_juridique_code || ' ' || + entreprises.nom_commercial || ' ' || + entreprises.raison_sociale || ' ' || + entreprises.siret_siege_social || ' ' || + entreprises.nom || ' ' || + entreprises.prenom || ' ' || + rna_informations.association_id || ' ' || + rna_informations.titre || ' ' || + rna_informations.objet AS term + FROM entreprises + INNER JOIN rna_informations ON rna_informations.entreprise_id = entreprises.id + +UNION SELECT etablissements.dossier_id, + etablissements.siret || ' ' || + etablissements.naf || ' ' || + etablissements.libelle_naf || ' ' || + etablissements.adresse || ' ' || + etablissements.code_postal || ' ' || + etablissements.localite || ' ' || + etablissements.code_insee_localite AS term + FROM etablissements + +UNION SELECT individuals.dossier_id, + individuals.nom || ' ' || + individuals.prenom AS term + FROM individuals + +UNION SELECT pieces_justificatives.dossier_id, + pieces_justificatives.content AS term + FROM pieces_justificatives + +UNION SELECT dossiers.id, + france_connect_informations.given_name || ' ' || + france_connect_informations.family_name AS term + FROM france_connect_informations + INNER JOIN dossiers ON dossiers.user_id = france_connect_informations.user_id diff --git a/spec/models/search_spec.rb b/spec/models/search_spec.rb new file mode 100644 index 000000000..89ac26d2d --- /dev/null +++ b/spec/models/search_spec.rb @@ -0,0 +1,5 @@ +require 'rails_helper' + +RSpec.describe Search, type: :model do + pending "add some examples to (or delete) #{__FILE__}" +end