From 53ad96b42cb7f94879b634ca0dfb67c67d9190a2 Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?J=C3=A9r=C3=B4me=20Burkard?= Date: Mon, 23 Sep 2024 14:28:29 +0200 Subject: [PATCH] split establishment locations in 2 tables (for perf reasons) --- back/src/config/pg/kysely/model/database.ts | 13 +- ...ions-in-2-for-performances-improvements.ts | 398 ++++++++++++++++++ ...shmentsToSuggestUpdate.integration.test.ts | 3 +- ...entAggregateRepository.integration.test.ts | 3 +- .../PgEstablishmentAggregateRepository.sql.ts | 2 +- .../PgEstablishmentAggregateRepository.ts | 91 ++-- .../PgGroupRepository.integration.test.ts | 3 +- .../adapters/PgGroupRepository.ts | 2 +- back/src/utils/db.integration.utils.ts | 12 +- 9 files changed, 482 insertions(+), 45 deletions(-) create mode 100644 back/src/config/pg/migrations/1727168535200_split-establishment-locations-in-2-for-performances-improvements.ts diff --git a/back/src/config/pg/kysely/model/database.ts b/back/src/config/pg/kysely/model/database.ts index 6c2e90516d..ed835a09b0 100644 --- a/back/src/config/pg/kysely/model/database.ts +++ b/back/src/config/pg/kysely/model/database.ts @@ -28,7 +28,8 @@ export interface Database { establishment_lead_events: EstablishmentLeadEvents; establishments_contacts: EstablishmentsContacts; establishments_deleted: EstablishmentsDeleted; - establishments_locations: EstablishmentsLocations; + establishments_location_infos: EstablishmentsLocationInfos; + establishments_location_positions: EstablishmentsLocationPositions; establishments: Establishments; exchanges: Exchanges; feature_flags: FeatureFlags; @@ -411,7 +412,12 @@ interface PublicRomesData { libelle_rome_tsvector: string | null; } -interface EstablishmentsLocations { +interface EstablishmentsLocationPositions { + id: string; + position: string; +} + +type EstablishmentsLocationInfos = { id: string; establishment_siret: string; post_code: string; @@ -420,8 +426,7 @@ interface EstablishmentsLocations { department_code: string; lat: number; lon: number; - position: string; -} +}; interface ImmersionOffers { rome_code: string; diff --git a/back/src/config/pg/migrations/1727168535200_split-establishment-locations-in-2-for-performances-improvements.ts b/back/src/config/pg/migrations/1727168535200_split-establishment-locations-in-2-for-performances-improvements.ts new file mode 100644 index 0000000000..bbb7484076 --- /dev/null +++ b/back/src/config/pg/migrations/1727168535200_split-establishment-locations-in-2-for-performances-improvements.ts @@ -0,0 +1,398 @@ +import { MigrationBuilder } from "node-pg-migrate"; + +const establishmentsLocations = "establishments_locations"; +const establishmentsLocationPositions = "establishments_location_positions"; +const establishmentsLocationInfos = "establishments_location_infos"; + +export async function up(pgm: MigrationBuilder): Promise { + dropDependantViews(pgm); + + pgm.createTable(establishmentsLocationInfos, { + id: { + type: "UUID", + primaryKey: true, + }, + establishment_siret: { + type: "CHAR(14)", + notNull: true, + references: "establishments", + onDelete: "CASCADE", + }, + post_code: { + type: "TEXT", + notNull: true, + }, + city: { + type: "TEXT", + notNull: true, + }, + street_number_and_address: { + type: "TEXT", + notNull: true, + }, + department_code: { + type: "TEXT", + notNull: true, + }, + lat: { + type: "DOUBLE PRECISION", + notNull: true, + }, + lon: { + type: "DOUBLE PRECISION", + notNull: true, + }, + }); + + pgm.createTable(establishmentsLocationPositions, { + id: { + type: "UUID", + primaryKey: true, + references: establishmentsLocationInfos, + onDelete: "CASCADE", + }, + position: { + type: "geography", + notNull: true, + }, + }); + + pgm.addIndex(establishmentsLocationInfos, "establishment_siret"); + pgm.addIndex(establishmentsLocationPositions, "position", { method: "gist" }); + + pgm.sql(` + INSERT INTO ${establishmentsLocationInfos} (id, establishment_siret, post_code, city, street_number_and_address, department_code, lat, lon) + SELECT id, establishment_siret, post_code, city, street_number_and_address, department_code, lat, lon + FROM ${establishmentsLocations}; + `); + + pgm.sql(` + INSERT INTO ${establishmentsLocationPositions} (id, position) + SELECT id, position + FROM ${establishmentsLocations}; + `); + + pgm.dropTable(establishmentsLocations); + + recreateDependantViews(pgm, "up"); +} + +export async function down(pgm: MigrationBuilder): Promise { + dropDependantViews(pgm); + + pgm.createTable(establishmentsLocations, { + id: { + type: "UUID", + primaryKey: true, + }, + position: { + type: "geography", + notNull: true, + }, + establishment_siret: { + type: "CHAR(14)", + notNull: true, + references: "establishments", + onDelete: "CASCADE", + }, + post_code: { + type: "TEXT", + notNull: true, + }, + city: { + type: "TEXT", + notNull: true, + }, + street_number_and_address: { + type: "TEXT", + notNull: true, + }, + department_code: { + type: "TEXT", + notNull: true, + }, + lat: { + type: "DOUBLE PRECISION", + notNull: true, + }, + lon: { + type: "DOUBLE PRECISION", + notNull: true, + }, + }); + + pgm.sql(` + insert into ${establishmentsLocations} + ${queryMergingTables} + `); + + pgm.addIndex(establishmentsLocations, "position", { method: "gist" }); + pgm.addIndex(establishmentsLocations, "establishment_siret"); + + pgm.dropTable(establishmentsLocationInfos); + pgm.dropTable(establishmentsLocationPositions); + + recreateDependantViews(pgm, "down"); +} + +const queryMergingTables = ` + SELECT + ${establishmentsLocationPositions}.id as id, + ${establishmentsLocationPositions}.position as position, + ${establishmentsLocationInfos}.establishment_siret as establishment_siret, + ${establishmentsLocationInfos}.post_code as post_code, + ${establishmentsLocationInfos}.city as city, + ${establishmentsLocationInfos}.street_number_and_address as street_number_and_address, + ${establishmentsLocationInfos}.department_code as department_code, + ${establishmentsLocationInfos}.lat as lat, + ${establishmentsLocationInfos}.lon as lon + FROM ${establishmentsLocationInfos} + inner join ${establishmentsLocationPositions} + on ${establishmentsLocationInfos}.id = ${establishmentsLocationPositions}.id +`; + +const dropDependantViews = (pgm: MigrationBuilder) => { + pgm.dropMaterializedView("view_establishments_with_aggregated_offers"); + pgm.dropMaterializedView("view_establishments_with_flatten_offers"); + pgm.dropMaterializedView("view_establishments"); + pgm.dropMaterializedView("view_siret_with_department_region"); + pgm.dropView("view_offers_from_form_establishment"); +}; + +const recreateDependantViews = ( + pgm: MigrationBuilder, + direction: Direction, +) => { + createSDRView(pgm, direction); + createEstablishmentsView(pgm, direction); + createEstablishmentsWithAggredatedOffersView(pgm); + createEstablishmentsWithFlattedOffersView(pgm); + createOffersFromFormEstablishmentsView(pgm, direction); +}; + +type Direction = "up" | "down"; + +const leftJoinLoc = (direction: Direction) => + direction === "up" + ? "LEFT JOIN establishments_location_infos loc ON loc.establishment_siret = e.siret" + : "LEFT JOIN establishments_locations loc ON loc.establishment_siret = e.siret"; + +const createSDRView = (pgm: MigrationBuilder, direction: Direction) => { + pgm.sql(` + create materialized view view_siret_with_department_region as + SELECT e.siret, + pdr.department_name, + pdr.region_name + FROM establishments e + ${leftJoinLoc(direction)} + LEFT JOIN public_department_region pdr ON pdr.department_code = loc.department_code; + `); +}; + +const createEstablishmentsView = ( + pgm: MigrationBuilder, + direction: Direction, +) => { + pgm.sql(` + create materialized view view_establishments as +WITH count_conventions_by_siret AS (SELECT conventions.siret, + count(*) AS count + FROM conventions + WHERE conventions.status::text = + 'ACCEPTED_BY_VALIDATOR'::text + GROUP BY conventions.siret), + count_contact_requests_by_siret + AS (SELECT DISTINCT count(discussions.siret) AS count, + discussions.siret + FROM discussions + GROUP BY discussions.siret) +SELECT DISTINCT e.created_at AS "Date de référencement", + e.update_date AS "Date de mise à jour", + e.siret AS "Siret", + e.name AS "Raison Sociale", + e.customized_name AS "Enseigne", + loc.street_number_and_address AS "Adresse", + loc.post_code AS "Code Postal", + loc.city AS "Ville", + sdr.department_name AS "Département", + sdr.region_name AS "Région", + e.naf_code AS "NAF", + pnc.class_id AS "Id Classe NAF", + pnc.class_label AS "Classe NAF", + pnc.group_id AS "Id Groupe NAF", + pnc.group_label AS "Groupe NAF", + pnc.division_id AS "Id Division NAF", + pnc.division_label AS "Division NAF", + pnc.section_id AS "Id Section NAF", + pnc.section_label AS "Section NAF", + e.number_employees AS "Nombre d’employés", + concat(ec.firstname, ec.lastname) AS "Contact", + ec.job AS "Rôle du contact", + ec.email AS "Email du contact", + ec.phone AS "Téléphone du contact", + CASE + WHEN ec.contact_mode = 'PHONE'::contact_mode + THEN 'Téléphone'::text + WHEN ec.contact_mode = 'IN_PERSON'::contact_mode + THEN 'En personne'::text + ELSE 'Email'::text + END AS "Mode de contact", + CASE + WHEN e.is_commited THEN 'Oui'::text + ELSE 'Non déclaré'::text + END AS "Appartenance Réseau « Les entreprises s’engagent »", + CASE + WHEN e.fit_for_disabled_workers THEN 'Oui'::text + ELSE 'Non'::text + END AS "Accueil les personnes en situation de handicap", + CASE + WHEN e.is_searchable THEN 'Oui'::text + ELSE 'Non'::text + END AS "Visible", + e.source_provider AS "Origine", + COALESCE(count_rel.count, 0::bigint) AS "Nombre de mise en relation pour cette entreprise", + COALESCE(count_conv.count, 0::bigint) AS "Nombre de convention validée pour cette entreprise" +FROM establishments e + LEFT JOIN establishments_contacts ec ON e.siret = ec.siret + LEFT JOIN view_siret_with_department_region sdr ON sdr.siret = e.siret + LEFT JOIN public_naf_classes_2008 pnc ON pnc.class_id::text = + regexp_replace( + e.naf_code::text, + '(\\d{2})(\\d{2}).*'::text, + '\\1.\\2'::text) + LEFT JOIN count_contact_requests_by_siret count_rel + ON count_rel.siret = e.siret + LEFT JOIN count_conventions_by_siret count_conv + ON count_conv.siret = e.siret + ${leftJoinLoc(direction)} + ; + `); +}; + +const createEstablishmentsWithAggredatedOffersView = ( + pgm: MigrationBuilder, +) => { + pgm.sql(` + create materialized view view_establishments_with_aggregated_offers as +WITH offers_by_siret AS (SELECT e.siret, + array_agg(pad.libelle_appellation_long) AS appelation_labels, + array_agg(io_1.rome_code) AS rome_codes + FROM establishments e + LEFT JOIN immersion_offers io_1 ON io_1.siret = e.siret + LEFT JOIN public_appellations_data pad + ON pad.code_rome::bpchar = + io_1.rome_code AND + pad.ogr_appellation = + io_1.appellation_code + GROUP BY e.siret) +SELECT view_establishments."Date de référencement", + view_establishments."Date de mise à jour", + view_establishments."Siret", + view_establishments."Raison Sociale", + view_establishments."Enseigne", + view_establishments."Adresse", + view_establishments."Code Postal", + view_establishments."Ville", + view_establishments."Département", + view_establishments."Région", + view_establishments."NAF", + view_establishments."Id Classe NAF", + view_establishments."Classe NAF", + view_establishments."Id Groupe NAF", + view_establishments."Groupe NAF", + view_establishments."Id Division NAF", + view_establishments."Division NAF", + view_establishments."Id Section NAF", + view_establishments."Section NAF", + view_establishments."Nombre d’employés", + view_establishments."Contact", + view_establishments."Rôle du contact", + view_establishments."Email du contact", + view_establishments."Téléphone du contact", + view_establishments."Mode de contact", + view_establishments."Appartenance Réseau « Les entreprises s’engagent »", + view_establishments."Accueil les personnes en situation de handicap", + view_establishments."Visible", + view_establishments."Origine", + view_establishments."Nombre de mise en relation pour cette entreprise", + view_establishments."Nombre de convention validée pour cette entreprise", + io.rome_codes AS "Codes Métier", + io.appelation_labels AS "Métiers" +FROM view_establishments + LEFT JOIN offers_by_siret io ON io.siret = view_establishments."Siret"; + `); +}; + +const createEstablishmentsWithFlattedOffersView = (pgm: MigrationBuilder) => { + pgm.sql(` + create materialized view view_establishments_with_flatten_offers as +WITH offers_by_siret AS (SELECT e.siret, + pad.libelle_appellation_long AS appelation_labels, + io_1.rome_code + FROM establishments e + LEFT JOIN immersion_offers io_1 ON io_1.siret = e.siret + LEFT JOIN public_appellations_data pad + ON pad.code_rome::bpchar = + io_1.rome_code AND + pad.ogr_appellation = + io_1.appellation_code) +SELECT view_establishments."Date de référencement", + view_establishments."Date de mise à jour", + view_establishments."Siret", + view_establishments."Raison Sociale", + view_establishments."Enseigne", + view_establishments."Adresse", + view_establishments."Code Postal", + view_establishments."Ville", + view_establishments."Département", + view_establishments."Région", + view_establishments."NAF", + view_establishments."Id Classe NAF", + view_establishments."Classe NAF", + view_establishments."Id Groupe NAF", + view_establishments."Groupe NAF", + view_establishments."Id Division NAF", + view_establishments."Division NAF", + view_establishments."Id Section NAF", + view_establishments."Section NAF", + view_establishments."Nombre d’employés", + view_establishments."Contact", + view_establishments."Rôle du contact", + view_establishments."Email du contact", + view_establishments."Téléphone du contact", + view_establishments."Mode de contact", + view_establishments."Appartenance Réseau « Les entreprises s’engagent »", + view_establishments."Accueil les personnes en situation de handicap", + view_establishments."Visible", + view_establishments."Origine", + view_establishments."Nombre de mise en relation pour cette entreprise", + view_establishments."Nombre de convention validée pour cette entreprise", + io.rome_code AS "Code Métier", + io.appelation_labels AS "Métier" +FROM view_establishments + LEFT JOIN offers_by_siret io ON io.siret = view_establishments."Siret"; + `); +}; + +const createOffersFromFormEstablishmentsView = ( + pgm: MigrationBuilder, + direction: Direction, +) => { + pgm.sql(` + create view view_offers_from_form_establishment + (update_date, name, rome_label, appellation_label, siret, + post_code) as +SELECT io.update_date, + e.name, + vad.rome_label, + vad.appellation_label, + io.siret, + loc.post_code +FROM immersion_offers io + LEFT JOIN establishments e ON io.siret = e.siret + LEFT JOIN view_appellations_dto vad + ON io.appellation_code = vad.appellation_code + ${leftJoinLoc(direction)} +ORDER BY (ROW (io.update_date, e.name)); + `); +}; diff --git a/back/src/domains/establishment/adapters/PgEstablishmentAggregateRepository.getSiretOfEstablishmentsToSuggestUpdate.integration.test.ts b/back/src/domains/establishment/adapters/PgEstablishmentAggregateRepository.getSiretOfEstablishmentsToSuggestUpdate.integration.test.ts index 97c6701661..9a05ff8a88 100644 --- a/back/src/domains/establishment/adapters/PgEstablishmentAggregateRepository.getSiretOfEstablishmentsToSuggestUpdate.integration.test.ts +++ b/back/src/domains/establishment/adapters/PgEstablishmentAggregateRepository.getSiretOfEstablishmentsToSuggestUpdate.integration.test.ts @@ -28,7 +28,8 @@ describe("PgScriptsQueries", () => { beforeEach(async () => { await db.deleteFrom("establishments_contacts").execute(); - await db.deleteFrom("establishments_locations").execute(); + await db.deleteFrom("establishments_location_infos").execute(); + await db.deleteFrom("establishments_location_positions").execute(); await db.deleteFrom("establishments").execute(); await db.deleteFrom("outbox_failures").execute(); await db.deleteFrom("outbox_publications").execute(); diff --git a/back/src/domains/establishment/adapters/PgEstablishmentAggregateRepository.integration.test.ts b/back/src/domains/establishment/adapters/PgEstablishmentAggregateRepository.integration.test.ts index be15d0f08e..d2a1a6fea0 100644 --- a/back/src/domains/establishment/adapters/PgEstablishmentAggregateRepository.integration.test.ts +++ b/back/src/domains/establishment/adapters/PgEstablishmentAggregateRepository.integration.test.ts @@ -52,7 +52,8 @@ describe("PgEstablishmentAggregateRepository", () => { await kyselyDb.deleteFrom("establishments_contacts").execute(); await kyselyDb.deleteFrom("immersion_offers").execute(); await kyselyDb.deleteFrom("discussions").execute(); - await kyselyDb.deleteFrom("establishments_locations").execute(); + await kyselyDb.deleteFrom("establishments_location_infos").execute(); + await kyselyDb.deleteFrom("establishments_location_positions").execute(); await kyselyDb.deleteFrom("establishments").execute(); pgEstablishmentAggregateRepository = new PgEstablishmentAggregateRepository( diff --git a/back/src/domains/establishment/adapters/PgEstablishmentAggregateRepository.sql.ts b/back/src/domains/establishment/adapters/PgEstablishmentAggregateRepository.sql.ts index c65b13ac32..43628d77ea 100644 --- a/back/src/domains/establishment/adapters/PgEstablishmentAggregateRepository.sql.ts +++ b/back/src/domains/establishment/adapters/PgEstablishmentAggregateRepository.sql.ts @@ -55,7 +55,7 @@ SELECT ) ) ) AS locations -FROM establishments_locations +FROM establishments_location_infos GROUP BY establishment_siret `; diff --git a/back/src/domains/establishment/adapters/PgEstablishmentAggregateRepository.ts b/back/src/domains/establishment/adapters/PgEstablishmentAggregateRepository.ts index 76deac804f..36121a8c14 100644 --- a/back/src/domains/establishment/adapters/PgEstablishmentAggregateRepository.ts +++ b/back/src/domains/establishment/adapters/PgEstablishmentAggregateRepository.ts @@ -1,5 +1,5 @@ import { sql } from "kysely"; -import { equals, keys, pick } from "ramda"; +import { equals, keys, map, pick } from "ramda"; import { AppellationAndRomeDto, AppellationCode, @@ -271,7 +271,7 @@ export class PgEstablishmentAggregateRepository public async insertEstablishmentAggregate(aggregate: EstablishmentAggregate) { await this.#insertEstablishmentFromAggregate(aggregate); - await this.#insertLocations(aggregate); + await this.#insertLocations(aggregate.establishment); await this.#insertContactFromAggregate(aggregate); await this.createImmersionOffersToEstablishments( aggregate.offers.map((immersionOffer) => ({ @@ -367,8 +367,9 @@ export class PgEstablishmentAggregateRepository ) ORDER BY ogr_appellation)) AS appellations, null AS distance_m, 1 AS row_number, - loc.*, - loc.id AS location_id, + loc_inf.*, + loc_inf.id AS location_id, + loc_pos.position, e.score, e.naf_code, e.is_searchable, @@ -383,10 +384,12 @@ export class PgEstablishmentAggregateRepository LEFT JOIN establishments e ON io.siret = e.siret LEFT JOIN public_appellations_data AS pad ON pad.ogr_appellation = io.appellation_code LEFT JOIN public_romes_data AS prd ON prd.code_rome = io.rome_code - LEFT JOIN establishments_locations AS loc ON loc.establishment_siret = io.siret - WHERE io.siret = $1 AND io.appellation_code = $2 AND loc.id = $3 - GROUP BY (io.siret, io.rome_code, prd.libelle_rome, location_id, e.naf_code, e.is_searchable, e.next_availability_date, e.name, e.website, - e.additional_information, e.customized_name, e.fit_for_disabled_workers, e.number_employees, e.score)`, + LEFT JOIN establishments_location_infos AS loc_inf ON loc_inf.establishment_siret = io.siret + LEFT JOIN establishments_location_positions AS loc_pos ON loc_inf.id = loc_pos.id + WHERE io.siret = $1 AND io.appellation_code = $2 AND loc_inf.id = $3 + GROUP BY (io.siret, io.rome_code, prd.libelle_rome, e.naf_code, e.is_searchable, e.next_availability_date, e.name, e.website, + e.additional_information, e.customized_name, e.fit_for_disabled_workers, e.number_employees, e.score, + loc_pos.id, loc_inf.id )`, [siret, appellationCode, locationId], ); const immersionSearchResultDto = immersionSearchResultDtos.at(0); @@ -503,29 +506,24 @@ export class PgEstablishmentAggregateRepository .where("siret", "=", establishment.siret) .execute(); + const establishmentLocationIds = await this.transaction + .selectFrom("establishments_location_infos") + .select("id") + .where("establishment_siret", "=", establishment.siret) + .execute() + .then(map(({ id }) => id)); + await this.transaction - .deleteFrom("establishments_locations") + .deleteFrom("establishments_location_infos") .where("establishment_siret", "=", establishment.siret) .execute(); await this.transaction - .insertInto("establishments_locations") - .values((eb) => - establishment.locations.map(({ address, id, position }) => ({ - id, - establishment_siret: establishment.siret, - city: address.city, - department_code: address.departmentCode, - post_code: address.postcode, - street_number_and_address: address.streetNumberAndAddress, - lat: position.lat, - lon: position.lon, - position: eb.fn("ST_MakePoint", [ - sql`${position.lon}, ${position.lat}`, - ]), - })), - ) + .deleteFrom("establishments_location_positions") + .where("id", "=", sql`ANY(${establishmentLocationIds})`) .execute(); + + await this.#insertLocations(establishment); } async #deleteEstablishmentContactBySiret(siret: SiretDto): Promise { @@ -792,19 +790,28 @@ export class PgEstablishmentAggregateRepository } } - async #insertLocations(aggregate: EstablishmentAggregate) { + async #insertLocations(establishment: EstablishmentEntity) { await this.transaction - .insertInto("establishments_locations") - .values((eb) => - aggregate.establishment.locations.map(({ position, address, id }) => ({ - id: id, - establishment_siret: aggregate.establishment.siret, + .insertInto("establishments_location_infos") + .values( + establishment.locations.map(({ position, address, id }) => ({ + id, + establishment_siret: establishment.siret, city: address.city, department_code: address.departmentCode, post_code: address.postcode, street_number_and_address: address.streetNumberAndAddress, lat: position.lat, lon: position.lon, + })), + ) + .execute(); + + await this.transaction + .insertInto("establishments_location_positions") + .values((eb) => + establishment.locations.map(({ position, id }) => ({ + id, position: eb.fn("ST_GeographyFromText", [ sql`${`POINT(${position.lon} ${position.lat})`}`, ]), @@ -913,8 +920,17 @@ const searchImmersionResultsQuery = ( (eb) => pipeWithValue( eb - .selectFrom("establishments_locations") - .select(["establishment_siret as siret", "id", "position"]), + .selectFrom("establishments_location_positions") + .innerJoin( + "establishments_location_infos", + "establishments_location_infos.id", + "establishments_location_positions.id", + ) + .select([ + "establishment_siret as siret", + "establishments_location_infos.id", + "position", + ]), (eb) => geoParams && hasSearchGeoParams(geoParams) ? eb.where(({ fn }) => @@ -983,7 +999,12 @@ const searchImmersionResultsQuery = ( .selectFrom("filtered_results as r") .innerJoin("establishments as e", "e.siret", "r.siret") .innerJoin("establishments_contacts as c", "c.siret", "r.siret") - .innerJoin("establishments_locations as loc", "loc.id", "r.loc_id") + .innerJoin("establishments_location_infos as loc", "loc.id", "r.loc_id") + .innerJoin( + "establishments_location_positions as loc_pos", + "loc.id", + "loc_pos.id", + ) .innerJoin( (eb) => eb.selectFrom("public_naf_classes_2008").selectAll().as("n"), (join) => @@ -1029,7 +1050,7 @@ const searchImmersionResultsQuery = ( ...(geoParams && hasSearchGeoParams(geoParams) ? { distance_m: fn("ST_Distance", [ - ref("loc.position"), + ref("loc_pos.position"), fn("ST_GeographyFromText", [ sql`${`POINT(${geoParams.lon} ${geoParams.lat})`}`, ]), diff --git a/back/src/domains/establishment/adapters/PgGroupRepository.integration.test.ts b/back/src/domains/establishment/adapters/PgGroupRepository.integration.test.ts index 116625aa0b..168e13b79e 100644 --- a/back/src/domains/establishment/adapters/PgGroupRepository.integration.test.ts +++ b/back/src/domains/establishment/adapters/PgGroupRepository.integration.test.ts @@ -69,7 +69,8 @@ describe("PgEstablishmentGroupRepository", () => { await db.deleteFrom("groups__sirets").execute(); await db.deleteFrom("groups").execute(); await db.deleteFrom("establishments_contacts").execute(); - await db.deleteFrom("establishments_locations").execute(); + await db.deleteFrom("establishments_location_infos").execute(); + await db.deleteFrom("establishments_location_positions").execute(); await db.deleteFrom("establishments").execute(); await db.deleteFrom("discussions").execute(); }); diff --git a/back/src/domains/establishment/adapters/PgGroupRepository.ts b/back/src/domains/establishment/adapters/PgGroupRepository.ts index 7b714b2096..a8c55343c5 100644 --- a/back/src/domains/establishment/adapters/PgGroupRepository.ts +++ b/back/src/domains/establishment/adapters/PgGroupRepository.ts @@ -63,7 +63,7 @@ export class PgGroupRepository implements GroupRepository { ), ) .leftJoin( - "establishments_locations as loc", + "establishments_location_infos as loc", "e.siret", "loc.establishment_siret", ) diff --git a/back/src/utils/db.integration.utils.ts b/back/src/utils/db.integration.utils.ts index f1be76dbd9..f3a21d45e3 100644 --- a/back/src/utils/db.integration.utils.ts +++ b/back/src/utils/db.integration.utils.ts @@ -63,7 +63,17 @@ export async function isDbEmpty(kyselyDb: KyselyDb) { [], ); expectToEqual( - await kyselyDb.selectFrom("establishments_locations").selectAll().execute(), + await kyselyDb + .selectFrom("establishments_location_infos") + .selectAll() + .execute(), + [], + ); + expectToEqual( + await kyselyDb + .selectFrom("establishments_location_positions") + .selectAll() + .execute(), [], ); expectToEqual(