diff --git a/app/models/search.rb b/app/models/search.rb index 74de5ae1e..34e8d08f1 100644 --- a/app/models/search.rb +++ b/app/models/search.rb @@ -46,12 +46,16 @@ class Search < ActiveRecord::Base search_term = self.class.connection.quote(to_tsquery) + dossier_ids = @gestionnaire.dossiers + .select(:id) + .where(archived: false) + .where.not(state: "draft") + q = self.class .select("DISTINCT(searches.dossier_id)") .select("COALESCE(ts_rank(to_tsvector('french', searches.term::text), to_tsquery('french', #{search_term})), 0) AS rank") .joins(:dossier) - .where(dossier_id: @gestionnaire.dossier_ids) - .where("dossiers.archived = ? AND dossiers.state != ?", false, "draft") + .where(dossier_id: dossier_ids) .where("to_tsvector('french', searches.term::text) @@ to_tsquery('french', #{search_term})") .order("rank DESC") .paginate(page: @page) diff --git a/db/migrate/20161102154835_update_searches_to_version_2.rb b/db/migrate/20161102154835_update_searches_to_version_2.rb new file mode 100644 index 000000000..55223b4cf --- /dev/null +++ b/db/migrate/20161102154835_update_searches_to_version_2.rb @@ -0,0 +1,9 @@ +class UpdateSearchesToVersion2 < ActiveRecord::Migration + def up + replace_view :searches, version: 2 + end + + def down + replace_view :searches, version: 1 + end +end diff --git a/db/structure.sql b/db/structure.sql index 02c8546cd..8b12f3907 100644 --- a/db/structure.sql +++ b/db/structure.sql @@ -982,40 +982,18 @@ CREATE TABLE users ( CREATE VIEW searches AS SELECT dossiers.id AS dossier_id, - (((dossiers.id)::text || ' '::text) || (COALESCE(users.email, ''::character varying))::text) AS term - FROM (dossiers + (((((((((((((((((((((((((((((((((((((((((((((((((((((((COALESCE(users.email, ''::character varying))::text || ' '::text) || (COALESCE(france_connect_informations.given_name, ''::character varying))::text) || ' '::text) || (COALESCE(france_connect_informations.family_name, ''::character varying))::text) || ' '::text) || (COALESCE(cerfas.content, ''::character varying))::text) || ' '::text) || (COALESCE(champs.value, ''::character varying))::text) || ' '::text) || (COALESCE(drop_down_lists.value, ''::character varying))::text) || ' '::text) || (COALESCE(entreprises.siren, ''::character varying))::text) || ' '::text) || (COALESCE(entreprises.numero_tva_intracommunautaire, ''::character varying))::text) || ' '::text) || (COALESCE(entreprises.forme_juridique, ''::character varying))::text) || ' '::text) || (COALESCE(entreprises.forme_juridique_code, ''::character varying))::text) || ' '::text) || (COALESCE(entreprises.nom_commercial, ''::character varying))::text) || ' '::text) || (COALESCE(entreprises.raison_sociale, ''::character varying))::text) || ' '::text) || (COALESCE(entreprises.siret_siege_social, ''::character varying))::text) || ' '::text) || (COALESCE(entreprises.nom, ''::character varying))::text) || ' '::text) || (COALESCE(entreprises.prenom, ''::character varying))::text) || ' '::text) || (COALESCE(rna_informations.association_id, ''::character varying))::text) || ' '::text) || (COALESCE(rna_informations.titre, ''::character varying))::text) || ' '::text) || COALESCE(rna_informations.objet, ''::text)) || ' '::text) || (COALESCE(etablissements.siret, ''::character varying))::text) || ' '::text) || (COALESCE(etablissements.naf, ''::character varying))::text) || ' '::text) || (COALESCE(etablissements.libelle_naf, ''::character varying))::text) || ' '::text) || (COALESCE(etablissements.adresse, ''::character varying))::text) || ' '::text) || (COALESCE(etablissements.code_postal, ''::character varying))::text) || ' '::text) || (COALESCE(etablissements.localite, ''::character varying))::text) || ' '::text) || (COALESCE(etablissements.code_insee_localite, ''::character varying))::text) || ' '::text) || (COALESCE(individuals.nom, ''::character varying))::text) || ' '::text) || (COALESCE(individuals.prenom, ''::character varying))::text) || ' '::text) || (COALESCE(pieces_justificatives.content, ''::character varying))::text) AS term + FROM ((((((((((dossiers JOIN users ON ((users.id = dossiers.user_id))) -UNION - SELECT cerfas.dossier_id, - COALESCE(cerfas.content, ''::character varying) AS term - FROM cerfas -UNION - SELECT champs.dossier_id, - (((COALESCE(champs.value, ''::character varying))::text || ' '::text) || (COALESCE(drop_down_lists.value, ''::character varying))::text) AS term - FROM (champs - JOIN drop_down_lists ON ((drop_down_lists.type_de_champ_id = champs.type_de_champ_id))) -UNION - SELECT entreprises.dossier_id, - (((((((((((((((((((((((COALESCE(entreprises.siren, ''::character varying))::text || ' '::text) || (COALESCE(entreprises.numero_tva_intracommunautaire, ''::character varying))::text) || ' '::text) || (COALESCE(entreprises.forme_juridique, ''::character varying))::text) || ' '::text) || (COALESCE(entreprises.forme_juridique_code, ''::character varying))::text) || ' '::text) || (COALESCE(entreprises.nom_commercial, ''::character varying))::text) || ' '::text) || (COALESCE(entreprises.raison_sociale, ''::character varying))::text) || ' '::text) || (COALESCE(entreprises.siret_siege_social, ''::character varying))::text) || ' '::text) || (COALESCE(entreprises.nom, ''::character varying))::text) || ' '::text) || (COALESCE(entreprises.prenom, ''::character varying))::text) || ' '::text) || (COALESCE(rna_informations.association_id, ''::character varying))::text) || ' '::text) || (COALESCE(rna_informations.titre, ''::character varying))::text) || ' '::text) || COALESCE(rna_informations.objet, ''::text)) AS term - FROM (entreprises + LEFT JOIN france_connect_informations ON ((france_connect_informations.user_id = dossiers.user_id))) + LEFT JOIN cerfas ON ((cerfas.dossier_id = dossiers.id))) + LEFT JOIN champs ON ((champs.dossier_id = dossiers.id))) + LEFT JOIN drop_down_lists ON ((drop_down_lists.type_de_champ_id = champs.type_de_champ_id))) + LEFT JOIN entreprises ON ((entreprises.dossier_id = dossiers.id))) LEFT JOIN rna_informations ON ((rna_informations.entreprise_id = entreprises.id))) -UNION - SELECT etablissements.dossier_id, - (((((((((((((COALESCE(etablissements.siret, ''::character varying))::text || ' '::text) || (COALESCE(etablissements.naf, ''::character varying))::text) || ' '::text) || (COALESCE(etablissements.libelle_naf, ''::character varying))::text) || ' '::text) || (COALESCE(etablissements.adresse, ''::character varying))::text) || ' '::text) || (COALESCE(etablissements.code_postal, ''::character varying))::text) || ' '::text) || (COALESCE(etablissements.localite, ''::character varying))::text) || ' '::text) || (COALESCE(etablissements.code_insee_localite, ''::character varying))::text) AS term - FROM etablissements -UNION - SELECT individuals.dossier_id, - (((COALESCE(individuals.nom, ''::character varying))::text || ' '::text) || (COALESCE(individuals.prenom, ''::character varying))::text) AS term - FROM individuals -UNION - SELECT pieces_justificatives.dossier_id, - COALESCE(pieces_justificatives.content, ''::character varying) AS term - FROM pieces_justificatives -UNION - SELECT dossiers.id AS dossier_id, - (((COALESCE(france_connect_informations.given_name, ''::character varying))::text || ' '::text) || (COALESCE(france_connect_informations.family_name, ''::character varying))::text) AS term - FROM (france_connect_informations - JOIN dossiers ON ((dossiers.user_id = france_connect_informations.user_id))); + LEFT JOIN etablissements ON ((etablissements.dossier_id = dossiers.id))) + LEFT JOIN individuals ON ((individuals.dossier_id = dossiers.id))) + LEFT JOIN pieces_justificatives ON ((pieces_justificatives.dossier_id = dossiers.id))); -- @@ -2075,3 +2053,5 @@ INSERT INTO schema_migrations (version) VALUES ('20161011125345'); INSERT INTO schema_migrations (version) VALUES ('20161025150900'); +INSERT INTO schema_migrations (version) VALUES ('20161102154835'); + diff --git a/db/views/searches_v01.sql b/db/views/searches_v01.sql index 221f1183a..e5f2cfd71 100644 --- a/db/views/searches_v01.sql +++ b/db/views/searches_v01.sql @@ -1,3 +1,6 @@ +-- this version allows to search for a single term within many tables, +-- but behaves badly with multiple terms scattered in multiple tables. + SELECT dossiers.id AS dossier_id, dossiers.id::text || ' ' || COALESCE(users.email, '') AS term diff --git a/db/views/searches_v02.sql b/db/views/searches_v02.sql new file mode 100644 index 000000000..8a168f465 --- /dev/null +++ b/db/views/searches_v02.sql @@ -0,0 +1,43 @@ +-- this version merges all possible search terms together, complicating the +-- view, but enables searching for multiple terms from multiple tables at once. + +SELECT dossiers.id AS dossier_id, + COALESCE(users.email, '') || ' ' || + COALESCE(france_connect_informations.given_name, '') || ' ' || + COALESCE(france_connect_informations.family_name, '') || ' ' || + COALESCE(cerfas.content, '') || ' ' || + COALESCE(champs.value, '') || ' ' || + COALESCE(drop_down_lists.value, '') || ' ' || + COALESCE(entreprises.siren, '') || ' ' || + COALESCE(entreprises.numero_tva_intracommunautaire, '') || ' ' || + COALESCE(entreprises.forme_juridique, '') || ' ' || + COALESCE(entreprises.forme_juridique_code, '') || ' ' || + COALESCE(entreprises.nom_commercial, '') || ' ' || + COALESCE(entreprises.raison_sociale, '') || ' ' || + COALESCE(entreprises.siret_siege_social, '') || ' ' || + COALESCE(entreprises.nom, '') || ' ' || + COALESCE(entreprises.prenom, '') || ' ' || + COALESCE(rna_informations.association_id, '') || ' ' || + COALESCE(rna_informations.titre, '') || ' ' || + COALESCE(rna_informations.objet, '') || ' ' || + COALESCE(etablissements.siret, '') || ' ' || + COALESCE(etablissements.naf, '') || ' ' || + COALESCE(etablissements.libelle_naf, '') || ' ' || + COALESCE(etablissements.adresse, '') || ' ' || + COALESCE(etablissements.code_postal, '') || ' ' || + COALESCE(etablissements.localite, '') || ' ' || + COALESCE(etablissements.code_insee_localite, '') || ' ' || + COALESCE(individuals.nom, '') || ' ' || + COALESCE(individuals.prenom, '') || ' ' || + COALESCE(pieces_justificatives.content, '') AS term +FROM dossiers +INNER JOIN users ON users.id = dossiers.user_id +LEFT JOIN france_connect_informations ON france_connect_informations.user_id = dossiers.user_id +LEFT JOIN cerfas ON cerfas.dossier_id = dossiers.id +LEFT JOIN champs ON champs.dossier_id = dossiers.id +LEFT JOIN drop_down_lists ON drop_down_lists.type_de_champ_id = champs.type_de_champ_id +LEFT JOIN entreprises ON entreprises.dossier_id = dossiers.id +LEFT JOIN rna_informations ON rna_informations.entreprise_id = entreprises.id +LEFT JOIN etablissements ON etablissements.dossier_id = dossiers.id +LEFT JOIN individuals ON individuals.dossier_id = dossiers.id +LEFT JOIN pieces_justificatives ON pieces_justificatives.dossier_id = dossiers.id diff --git a/spec/models/search_spec.rb b/spec/models/search_spec.rb index 2e18d5d35..4e7d20ec2 100644 --- a/spec/models/search_spec.rb +++ b/spec/models/search_spec.rb @@ -5,13 +5,8 @@ describe Search do subject { liste_dossiers } let(:liste_dossiers) do - #described_class.refresh described_class.new(gestionnaire: gestionnaire_1, query: terms).results end - #let(:dossier) do - # described_class.refresh - # described_class.search(gestionnaire: gestionnaire_1, query: terms)[1] - #end let(:administrateur_1) { create(:administrateur) } let(:administrateur_2) { create(:administrateur) } @@ -55,12 +50,6 @@ describe Search do it { expect(subject.size).to eq(0) } end - #describe 'search on ID dossier' do - # let(:terms) { "#{dossier_2.id}" } - - # it { expect(dossier.id).to eq(dossier_2.id) } - #end - describe 'search on SIRET' do context 'when is part of SIRET' do let(:terms) { '4181' } @@ -82,9 +71,9 @@ describe Search do end describe 'search on multiple fields' do - let(:terms) { 'octo test' } + let(:terms) { 'octo plop' } - pending { expect(subject.size).to eq(1) } + it { expect(subject.size).to eq(1) } end end end