Skip to content

Commit

Permalink
add use case function to select calculate address postal code
Browse files Browse the repository at this point in the history
  • Loading branch information
Jugurtha Bouhadoun committed Jun 27, 2024
1 parent 296027b commit ddbc1e9
Show file tree
Hide file tree
Showing 2 changed files with 151 additions and 89 deletions.
133 changes: 60 additions & 73 deletions db-migrations/migrations/20240625132013-init-postal-code-view.cjs
Original file line number Diff line number Diff line change
Expand Up @@ -7,70 +7,64 @@ module.exports = {
async up(queryInterface) {
try {
// Create the address_view

await queryInterface.sequelize.query(`
CREATE VIEW ban."address_view_cp" AS
WITH postal_codes_array AS (
SELECT
a.id,
a."mainCommonToponymID",
a."secondaryCommonToponymIDs",
a.labels,
a.suffix,
a.positions,
a.certified,
a.bbox,
array_length(d."postalCodes", 1) AS array_length,
d."postalCodes" AS ps,
b.meta->'insee'->>'cog' AS insee_com,
d."libelleAcheminement"
FROM
ban.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.insee_com,
CASE
WHEN pca.array_length = 1 THEN pca.ps[1]
WHEN pca.array_length > 1 AND EXISTS (
SELECT 1
FROM external.postal_area AS c
WHERE ST_Intersects(ST_Transform(pca.bbox, 2154), ST_Transform(c.geometry, 2154)))
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 'DATANOVA'
WHEN pca.array_length > 1 AND
EXISTS (
SELECT 1
FROM external.postal_area AS c
WHERE ST_Intersects(ST_Transform(pca.bbox, 2154), ST_Transform(c.geometry, 2154)))
THEN 'CONTOURS_CP'
ELSE 'DGFIP'
END AS source_cp,
pca."libelleAcheminement",
pca.labels,
pca.suffix,
pca.positions,
pca.certified,
pca.bbox
FROM
postal_codes_array AS pca
ORDER BY pca.id ASC
CREATE VIEW ban."address_view_cp" AS
WITH postal_codes_array AS (
SELECT
a.id,
a."mainCommonToponymID",
a."secondaryCommonToponymIDs",
a.labels,
a.suffix,
a.positions,
a.certified,
a.bbox,
array_length(d."postalCodes", 1) AS array_length,
d."postalCodes" AS ps,
b.meta->'insee'->>'cog' AS insee_com,
d."libelleAcheminement"
FROM
ban.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.insee_com,
CASE
WHEN pca.array_length = 1 THEN pca.ps[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 'DATANOVA'
WHEN pca.array_length > 1
THEN 'CONTOURS_CP'
ELSE 'DGFIP'
END AS source_cp,
pca."libelleAcheminement",
pca.labels,
pca.suffix,
pca.positions,
pca.certified,
pca.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}";`)

Expand Down Expand Up @@ -110,11 +104,8 @@ module.exports = {
pca.insee_com,
CASE
WHEN pca.array_length = 1 THEN pca.ps[1]
WHEN pca.array_length > 1 AND EXISTS (
SELECT 1
FROM external.postal_area AS c
WHERE ST_Intersects(ST_Transform(pca.used_bbox, 2154), ST_Transform(c.geometry, 2154))
) THEN (
WHEN pca.array_length > 1
THEN (
SELECT c."postalCode"
FROM external.postal_area AS c
WHERE pca.insee_com = c."inseeCom"
Expand All @@ -125,11 +116,7 @@ module.exports = {
END AS postal_code,
CASE
WHEN pca.array_length = 1 THEN 'DATANOVA'
WHEN pca.array_length > 1 AND EXISTS (
SELECT 1
FROM external.postal_area AS c
WHERE ST_Intersects(ST_Transform(pca.used_bbox, 2154), ST_Transform(c.geometry, 2154))
) THEN 'CONTOURS_CP'
WHEN pca.array_length > 1 THEN 'CONTOURS_CP'
ELSE 'DGFIP'
END AS source_cp,
pca."libelleAcheminement",
Expand Down
107 changes: 91 additions & 16 deletions lib/api/consumers/export-to-exploitation-db-consumer.js
Original file line number Diff line number Diff line change
Expand Up @@ -132,7 +132,7 @@ export default async function exportToExploitationDB({data}) {
raw: true,
})
// Format the data and calculate the fantoir code, tiles and postal code
const pageDataWithExtraDataCalculation = pageData.map(commonToponym => calculateExtraDataForCommonToponym(commonToponym, cog, fantoirFinder, commonToponymIDFantoirCodeMap))
const pageDataWithExtraDataCalculation = await Promise.all(pageData.map(async commonToponym => calculateExtraDataForCommonToponym(commonToponym, cog, fantoirFinder, commonToponymIDFantoirCodeMap)))
const formatedPageDataForLegacy = pageDataWithExtraDataCalculation.map(commonToponym => formatCommonToponymDataForLegacy(commonToponym, district, pseudoCodeVoieGenerator, commonToponymLegacyIDCommonToponymIDMap, commonToponymLegacyIDSet))

// Insert the data in the collection (legacy and banID)
Expand Down Expand Up @@ -169,7 +169,7 @@ export default async function exportToExploitationDB({data}) {
})

// Format the data and calculate the fantoir code, tiles and postal code
const pageDataWithExtraDataCalculation = pageData.map(address => calculateExtraDataForAddress(address, cog, commonToponymIDFantoirCodeMap))
const pageDataWithExtraDataCalculation = await Promise.all(pageData.map(async address => calculateExtraDataForAddress(address, cog, commonToponymIDFantoirCodeMap)))
const formatedPageDataForLegacy = pageDataWithExtraDataCalculation.map(address => formatAddressDataForLegacy(address, district, commonToponymLegacyIDCommonToponymIDMap, addressLegacyIDSet))

// Insert the data in the collection (legacy and banID)
Expand Down Expand Up @@ -212,13 +212,13 @@ const deleteAllLegacyDataRelatedToCOG = async cog => {
}

// Helpers for calculation
export const calculateExtraDataForCommonToponym = (commonToponym, cog, fantoirFinder, commonToponymIDFantoirCodeMap) => {
export const calculateExtraDataForCommonToponym = async (commonToponym, cog, fantoirFinder, commonToponymIDFantoirCodeMap) => {
// Calculate the fantoir code for each common toponym
const fantoirCode = calculateCommonToponymFantoirCode(commonToponymIDFantoirCodeMap, commonToponym, fantoirFinder)
// Calculate the tiles for each common toponym
const {geometry, tiles, x, y} = calculateCommonToponymGeometryAndTiles(commonToponym)
// Calculate the postal code for each common toponym
const {codePostal: postalCode, libelleAcheminement: deliveryLabel} = calculateCommonToponymPostalCode(commonToponymIDFantoirCodeMap, commonToponym, cog)
const {codePostal: postalCode, libelleAcheminement: deliveryLabel} = await calculateCommonToponymPostalCode(commonToponymIDFantoirCodeMap, commonToponym, cog)
// Remove the centroid data from the common toponym
return {...commonToponym,
geometry,
Expand All @@ -230,11 +230,11 @@ export const calculateExtraDataForCommonToponym = (commonToponym, cog, fantoirFi
}}
}

export const calculateExtraDataForAddress = (address, cog, commonToponymIDFantoirCodeMap) => {
export const calculateExtraDataForAddress = async (address, cog, commonToponymIDFantoirCodeMap) => {
// Calculate the tiles for each address
const {tiles, x, y} = calculateAddressTiles(address)
// Calculate the postal code for each address
const {codePostal: postalCode, libelleAcheminement: deliveryLabel} = calculateAddressPostalCode(commonToponymIDFantoirCodeMap, address, cog)
const {codePostal: postalCode, libelleAcheminement: deliveryLabel} = await calculateAddressPostalCode(commonToponymIDFantoirCodeMap, address, cog)
return {...address,
meta: {
...address.meta,
Expand Down Expand Up @@ -272,21 +272,96 @@ const calculateFantoirCode = (fantoirFinder, labelValue, codeAncienneCommune) =>
return fantoirData.successeur?.split('-')?.[1] || fantoirData.codeFantoir
}

const queryCalculateCommonToponymPostalCode = async replacements => {
const query = `
SELECT
postal_code,"libelleAcheminement",source_cp
FROM
ban.common_toponym_view_cp
WHERE id = :id
LIMIT 1
`
try {
const result = await sequelize.query(query, {replacements})
return result[0] // Assuming the first result is what you need
} catch (error) {
console.error('Error querying database:', error)
throw error
}
}

// Helpers to calculate the postal code
const calculateCommonToponymPostalCode = (commonToponymIDFantoirCodeMap, commonToponym, cog) => {
const fantoirCode = commonToponymIDFantoirCodeMap.get(commonToponym.id)
const {codePostal, libelleAcheminement} = findCodePostal(cog, fantoirCode)
return {codePostal, libelleAcheminement}
const calculateCommonToponymPostalCode = async (commonToponymIDFantoirCodeMap, commonToponym, cog) => {
try {
const result = await queryCalculateCommonToponymPostalCode({id: commonToponym.id})
const fantoirCode = commonToponymIDFantoirCodeMap.get(commonToponym.id)
let codePostal
let libelleAcheminement
if (result.length > 0) {
const firstResult = result[0]
if (firstResult.postal_code === null || firstResult.libelleAcheminement === null || firstResult.source_cp === 'DGFIP') {
({codePostal, libelleAcheminement} = findCodePostal(cog, fantoirCode))
} else {
codePostal = firstResult.postal_code
libelleAcheminement = firstResult.libelleAcheminement
}
} else {
({codePostal, libelleAcheminement} = findCodePostal(cog, fantoirCode))
}

return {codePostal, libelleAcheminement}
} catch (error) {
console.error('Error querying database:', error)
throw error
}
}

const calculateAddressPostalCode = (commonToponymIDFantoirCodeMap, address, cog) => {
const fantoirCode = commonToponymIDFantoirCodeMap.get(address.mainCommonToponymID)
const {number, suffix} = address
const {codePostal, libelleAcheminement} = findCodePostal(cog, fantoirCode, number, suffix)
return {codePostal, libelleAcheminement}
const queryCalculateAddressPostalCode = async replacements => {
const query = `
SELECT
postal_code,"libelleAcheminement",source_cp
FROM
ban.address_view_cp
WHERE id = :id
LIMIT 1
`
try {
const result = await sequelize.query(query, {replacements})
return result[0] // Assuming the first result is what you need
} catch (error) {
console.error('Error querying database:', error)
throw error
}
}

const calculateAddressPostalCode = async (commonToponymIDFantoirCodeMap, address, cog) => {
try {
const result = await queryCalculateAddressPostalCode({id: address.id})
const fantoirCode = commonToponymIDFantoirCodeMap.get(address.mainCommonToponymID)
const {number, suffix} = address

let codePostal
let libelleAcheminement

if (result.length > 0) {
const firstResult = result[0]
if (firstResult.postal_code === null || firstResult.libelleAcheminement === null || firstResult.source_cp === 'DGFIP') {
({codePostal, libelleAcheminement} = findCodePostal(cog, fantoirCode, number, suffix))
} else {
codePostal = firstResult.postal_code
libelleAcheminement = firstResult.libelleAcheminement
}
} else {
({codePostal, libelleAcheminement} = findCodePostal(cog, fantoirCode, number, suffix))
}

return {codePostal, libelleAcheminement}
} catch (error) {
console.error('Error querying database:', error)
throw error
}
}

// Helpers to calculate the tiles
const calculateCommonToponymGeometryAndTiles = commonToponym => {
const {geometry: geometryFromCommonToponym, centroid} = commonToponym
let geometryFromCentroid
Expand Down

0 comments on commit ddbc1e9

Please sign in to comment.