Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Added dynamic views (instead of the stored views) #491

Merged
merged 1 commit into from
Dec 10, 2024
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
209 changes: 209 additions & 0 deletions db-migrations/migrations/20241122171119-delete-views.cjs
Original file line number Diff line number Diff line change
@@ -0,0 +1,209 @@
'use strict'

const {POSTGRES_BAN_USER} = process.env

const bboxBufferAdressView = 50
const addressBboxBuffer = 200
const bboxBuffer = 100

/** @type {import('sequelize-cli').Migration} */
module.exports = {
async up(queryInterface,) {
await queryInterface.sequelize.query('DROP VIEW IF EXISTS ban."address_view_cp";')
await queryInterface.sequelize.query('DROP VIEW IF EXISTS ban."common_toponym_view_cp";')
},

async down(queryInterface) {
await queryInterface.sequelize.query(`
CREATE VIEW ban."address_view_cp" AS
WITH address_view AS (
SELECT
A.*,
ST_Transform(ST_Buffer(ST_Transform(ST_Envelope(ST_SetSRID(ST_GeomFromGeoJSON((A.positions[1])->'geometry'), 4326)), 2154), ${bboxBufferAdressView}, 'join=mitre endcap=square'), 4326) AS bbox
FROM
ban.address AS A
WHERE A."isActive" = true
ORDER BY A.id ASC ),
postal_codes_array AS (
SELECT
a.*,
array_length(d."postalCodes", 1) AS array_length,
d."postalCodes" AS postalCodes,
b.meta->'insee'->>'cog' AS insee_com,
d."libelleAcheminementWithPostalCodes"
FROM
address_view AS a
LEFT JOIN
ban.district AS b
ON a."districtID" = b.id
LEFT JOIN
external.datanova AS d
ON b.meta->'insee'->>'cog' = d."inseeCom"
)
SELECT
pca.id,
pca."mainCommonToponymID",
pca."secondaryCommonToponymIDs",
pca."districtID",
pca."number",
pca."suffix",
pca."labels",
pca."certified",
pca."positions",
pca."updateDate",
pca."meta",
pca."range_validity",
pca."isActive",
pca."bbox",
pca.insee_com,
CASE
WHEN pca.array_length = 1 THEN pca.postalCodes[1]
WHEN pca.array_length > 1
THEN (
SELECT c."postalCode"
FROM external.postal_area AS c
WHERE pca.insee_com = c."inseeCom"
ORDER BY ST_Area(ST_Intersection(ST_Transform(pca.bbox, 2154), ST_Transform(c.geometry, 2154))) desc
LIMIT 1
)
ELSE NULL
END AS postal_code,
CASE
WHEN pca.array_length = 1 THEN pca."libelleAcheminementWithPostalCodes"->>pca.postalCodes[1]
WHEN pca.array_length > 1
THEN (
SELECT pca."libelleAcheminementWithPostalCodes"->>c."postalCode"
FROM external.postal_area AS c
WHERE pca.insee_com = c."inseeCom"
ORDER BY ST_Area(ST_Intersection(ST_Transform(pca.bbox, 2154), ST_Transform(c.geometry, 2154))) DESC
LIMIT 1
)
ELSE NULL
END AS "libelleAcheminement",
pca.postalCodes,
pca."libelleAcheminementWithPostalCodes",
CASE
WHEN pca.array_length = 1 THEN 'DATANOVA'
WHEN pca.array_length > 1 THEN
CASE
WHEN EXISTS (
SELECT 1
FROM external.postal_area AS c
WHERE pca.insee_com = c."inseeCom"
AND ST_Intersects(ST_Transform(pca.bbox, 2154), ST_Transform(c.geometry, 2154))
) THEN 'CONTOURS_CP'
ELSE 'DGFIP'
END
ELSE 'DGFIP'
END AS source_cp
FROM
postal_codes_array AS pca
ORDER BY pca.id ASC
`)
await queryInterface.sequelize.query(`
CREATE VIEW ban."common_toponym_view_cp" AS
WITH common_toponym_view AS(
SELECT
CT.id, CT."districtID", CT.labels, CT.geometry, CT."updateDate", CT.meta, CT.range_validity, CT."isActive",
ST_Centroid(ST_Collect(ST_SetSRID(ST_GeomFromGeoJSON((A.positions[1])->'geometry'), 4326))) AS centroid,
ST_Transform(ST_Buffer(ST_Transform(ST_Envelope(ST_Collect(ST_SetSRID(ST_GeomFromGeoJSON((A.positions[1])->'geometry'), 4326))), 2154), ${addressBboxBuffer}, 'join=mitre endcap=square'), 4326) AS "addressBbox",
ST_Transform(ST_Buffer(ST_Transform(ST_Envelope(ST_SetSRID(ST_GeomFromGeoJSON(CT.geometry), 4326)), 2154), ${bboxBuffer}, 'join=mitre endcap=square'), 4326) AS "bbox",
COUNT(A.id) AS "addressCount",
COUNT(DISTINCT CASE WHEN A.certified = true THEN A.id ELSE NULL END) AS "certifiedAddressCount"
FROM
ban.common_toponym AS CT
LEFT JOIN
ban.address AS A
ON
(CT.id = A."mainCommonToponymID"
OR CT.id = ANY(A."secondaryCommonToponymIDs")) AND A."isActive" = true
WHERE CT."isActive" = true
GROUP BY CT.id
ORDER BY CT.id ASC ),

postal_codes_array AS (
SELECT
ct.*,
b.meta->'insee'->>'cog' AS insee_com,
array_length(d."postalCodes", 1) AS array_length,
d."postalCodes" AS postalCodes,
d."libelleAcheminementWithPostalCodes",
CASE
WHEN ct."addressCount" = 0 THEN ct.bbox
ELSE ct."addressBbox"
END AS used_bbox
FROM
common_toponym_view AS ct
LEFT JOIN
ban.district AS b
ON ct."districtID" = b.id
LEFT JOIN
external.datanova AS d
ON b.meta->'insee'->>'cog' = d."inseeCom"
)
SELECT
pca.id,
pca."districtID",
pca.labels,
pca.geometry,
pca."updateDate",
pca.meta,
pca.range_validity,
pca."isActive",
pca.centroid,
pca."addressBbox",
pca.bbox,
pca."addressCount",
pca."certifiedAddressCount",
pca.insee_com,
CASE
WHEN pca.array_length = 1 THEN pca.postalCodes[1]
WHEN pca.array_length > 1
THEN (
SELECT c."postalCode"
FROM external.postal_area AS c
WHERE pca.insee_com = c."inseeCom"
ORDER BY ST_Area(ST_Intersection(ST_Transform(pca.used_bbox, 2154), ST_Transform(c.geometry, 2154))) DESC
LIMIT 1
)
ELSE NULL
END AS postal_code,
CASE
WHEN pca.array_length = 1 THEN pca."libelleAcheminementWithPostalCodes"->>pca.postalCodes[1]
WHEN pca.array_length > 1
THEN (
SELECT pca."libelleAcheminementWithPostalCodes"->>c."postalCode"
FROM external.postal_area AS c
WHERE pca.insee_com = c."inseeCom"
ORDER BY ST_Area(ST_Intersection(ST_Transform(pca.bbox, 2154), ST_Transform(c.geometry, 2154))) DESC
LIMIT 1
)
ELSE NULL
END AS "libelleAcheminement",
pca.postalCodes,
pca."libelleAcheminementWithPostalCodes",
CASE
WHEN pca.array_length = 1 THEN 'DATANOVA'
WHEN pca.array_length > 1 THEN
CASE
WHEN EXISTS (
SELECT 1
FROM external.postal_area AS c
WHERE pca.insee_com = c."inseeCom"
AND ST_Intersects(ST_Transform(pca.used_bbox, 2154), ST_Transform(c.geometry, 2154))
) THEN 'CONTOURS_CP'
ELSE 'DGFIP'
END
ELSE 'DGFIP'
END AS source_cp,
pca.used_bbox
FROM
postal_codes_array AS pca
ORDER BY pca.id ASC
`)

await queryInterface.sequelize.query(`GRANT SELECT ON ban."address_view_cp" TO "${POSTGRES_BAN_USER}";`)
await queryInterface.sequelize.query(`GRANT SELECT ON ban."common_toponym_view_cp" TO "${POSTGRES_BAN_USER}";`)
}
}

Original file line number Diff line number Diff line change
@@ -0,0 +1,18 @@
'use strict'

const {POSTGRES_BAN_USER} = process.env

/** @type {import('sequelize-cli').Migration} */
module.exports = {
async up(queryInterface) {
await queryInterface.sequelize.query(`GRANT USAGE ON SCHEMA external TO "${POSTGRES_BAN_USER}";`)
await queryInterface.sequelize.query(`GRANT ALL PRIVILEGES ON SCHEMA external TO "${POSTGRES_BAN_USER}";`)
await queryInterface.sequelize.query(`GRANT ALL PRIVILEGES ON ALL TABLES IN SCHEMA external TO "${POSTGRES_BAN_USER}";`)
},

async down(queryInterface) {
await queryInterface.sequelize.query(`REVOKE USAGE ON SCHEMA external FROM "${POSTGRES_BAN_USER}";`)
await queryInterface.sequelize.query(`REVOKE ALL PRIVILEGES ON SCHEMA external FROM "${POSTGRES_BAN_USER}";`)
await queryInterface.sequelize.query(`REVOKE ALL PRIVILEGES ON ALL TABLES IN SCHEMA external FROM "${POSTGRES_BAN_USER}";`)
}
}
52 changes: 1 addition & 51 deletions lib/api/consumers/export-to-exploitation-db-consumer.js
Original file line number Diff line number Diff line change
Expand Up @@ -8,6 +8,7 @@ import {derivePositionProps} from '../../util/geo.cjs'
import {createPseudoCodeVoieGenerator} from '../../pseudo-codes-voies.cjs'
import gazetteerPromise from '../../util/gazetteer.cjs'

import {createCommonToponymTempTableQuery, createAddressTempTableQuery, countQuery, pageQuery, specificCommonToponymTempTableCountQuery, addressCertifiedTempTableCountQuery} from './sql-queries.js'
import {formatCommonToponymDataForLegacy, formatAddressDataForLegacy, formatDistrictDataForLegacy} from './format-to-legacy-helpers.js'

// SETTINGS
Expand Down Expand Up @@ -37,57 +38,6 @@ const EXPLOITATION_DB_COLLECTION_NAMES = {
address: 'numeros'
}

// QUERIES
const createCommonToponymTempTableQuery = tempTableName => `
CREATE TEMP TABLE ${tempTableName} AS
SELECT
CTV.*
FROM
ban.common_toponym_view_cp AS CTV
WHERE CTV."districtID" = :districtID
`

const createAddressTempTableQuery = tempTableName => `
CREATE TEMP TABLE ${tempTableName} AS
SELECT
AV.*
FROM
ban.address_view_cp AS AV
WHERE AV."districtID" = :districtID
`

const pageQuery = tempTableName => `
SELECT
*
FROM
${tempTableName}
OFFSET :offset
LIMIT :limit
`

const countQuery = tempTableName => `
SELECT
COUNT(*)
FROM
${tempTableName}
`

const specificCommonToponymTempTableCountQuery = tempTableName => `
SELECT
COUNT(*)
FROM
${tempTableName}
WHERE meta->'bal'->>'isLieuDit' = 'true';
`

const addressCertifiedTempTableCountQuery = tempTableName => `
SELECT
COUNT(*)
FROM
${tempTableName}
WHERE certified = TRUE;
`

export default async function exportToExploitationDB({data}) {
const {districtID} = data
console.log(`Exporting districtID ${districtID} to exploitation DB...`)
Expand Down
5 changes: 2 additions & 3 deletions lib/api/consumers/format-to-legacy-helpers.js
Original file line number Diff line number Diff line change
Expand Up @@ -71,7 +71,7 @@ export const formatDistrictDataForLegacy = async (district, {totalCommonToponymR

export const formatCommonToponymDataForLegacy = async (commonToponym, {district, pseudoCodeVoieGenerator, commonToponymLegacyIDCommonToponymIDMap, commonToponymLegacyIDSet, gazetteerFinder}) => {
const {labels: districtLabels, meta: {insee: {cog}}} = district
const {id, districtID, geometry, labels, meta, updateDate, addressCount, certifiedAddressCount, bbox, addressBbox} = commonToponym
const {id, districtID, geometry, labels, meta, updateDate, addressCount, certifiedAddressCount, bbox} = commonToponym

// Labels
// District
Expand All @@ -91,7 +91,6 @@ export const formatCommonToponymDataForLegacy = async (commonToponym, {district,
const lon = legacyPosition?.coordinates?.[0]
const lat = legacyPosition?.coordinates?.[1]
const commonToponymBbox = formatBboxForLegacy(bbox)
const commonToponymAddressBbox = formatBboxForLegacy(addressBbox)

// Old district
const {codeAncienneCommune, nomAncienneCommune} = await calculateLegacyCommuneAncienne(cog, meta, lon, lat, gazetteerFinder)
Expand Down Expand Up @@ -161,7 +160,7 @@ export const formatCommonToponymDataForLegacy = async (commonToponym, {district,
sourceNomVoie: 'bal',
position: legacyPosition,
codePostal: meta?.laposte?.codePostal,
displayBBox: commonToponymAddressBbox,
displayBBox: commonToponymBbox,
lon,
lat,
x: meta?.geography?.x,
Expand Down
Loading
Loading