Skip to content

Commit

Permalink
add views
Browse files Browse the repository at this point in the history
  • Loading branch information
jbouhadoun committed Jun 18, 2024
1 parent cc86730 commit 949c3c9
Show file tree
Hide file tree
Showing 3 changed files with 108 additions and 75 deletions.
47 changes: 47 additions & 0 deletions db-migrations/migrations/20240618130241-common_toponym_view.cjs
Original file line number Diff line number Diff line change
@@ -0,0 +1,47 @@
'use strict'

const {POSTGRES_BAN_USER} = process.env

/** @type {import('sequelize-cli').Migration} */
module.exports = {
async up(queryInterface) {
const addressBboxBuffer = 200;
const bboxBuffer = 100;
try {
// Execute the view creation
await queryInterface.sequelize.query(`
CREATE VIEW ban."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 `
)
// Grant permissions to ban user
await queryInterface.sequelize.query(`GRANT SELECT ON ban."common_toponym_view" TO "${POSTGRES_BAN_USER}";`)
} catch (error) {
console.lhog(error);
}
},

async down(queryInterface) {
try {
// Drop the view if it exists
await queryInterface.sequelize.query('DROP VIEW IF EXISTS ban."common_toponym_view" ;');
} catch (error) {
console.log(error);
}
}
}
35 changes: 35 additions & 0 deletions db-migrations/migrations/20240618130303-address_view.cjs
Original file line number Diff line number Diff line change
@@ -0,0 +1,35 @@
'use strict'

const {POSTGRES_BAN_USER} = process.env

/** @type {import('sequelize-cli').Migration} */
module.exports = {
async up(queryInterface) {
const bboxBuffer = 100;
try {
// Create the address_view
await queryInterface.sequelize.query(`
CREATE VIEW ban."address_view" AS
SELECT
A.*,
ST_Transform(ST_Buffer(ST_Transform(ST_Envelope(ST_SetSRID(ST_GeomFromGeoJSON((A.positions[1])->'geometry'), 4326)), 2154), ${bboxBuffer}, 'join=mitre endcap=square'), 4326) AS bbox
FROM
ban.address AS A
WHERE A."isActive" = true
ORDER BY A.id ASC
`)
await queryInterface.sequelize.query(`GRANT SELECT ON ban."address_view" TO "${POSTGRES_BAN_USER}";`);
} catch (error) {
console.log(error);
}
},

async down(queryInterface) {
try {
// Drop the address_view if it exists
await queryInterface.sequelize.query('DROP VIEW IF EXISTS ban."address_view";');
} catch (error) {
console.log(error);
}
}
}
101 changes: 26 additions & 75 deletions lib/api/consumers/export-to-exploitation-db-consumer.js
Original file line number Diff line number Diff line change
Expand Up @@ -36,16 +36,9 @@ const ADDRESS_BBOX_BUFFER = 50

// Collections names
const EXPLOITATION_DB_COLLECTION_NAMES = {
legacy: {
district: 'communes_temp',
commonToponym: 'voies_temp',
address: 'numeros_temp'
},
banID: {
district: 'district',
commonToponym: 'common_toponym',
address: 'address'
}
district: 'communes',
commonToponym: 'voies',
address: 'numeros'
}

// QUERIES & POSTGIS FUNCTIONS
Expand All @@ -56,22 +49,10 @@ const EXPLOITATION_DB_COLLECTION_NAMES = {

const commonToponymPageQuery = `
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"
CTV.*
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."districtID" = :districtID AND CT."isActive" = true
GROUP BY CT.id
ORDER BY CT.id ASC
ban.common_toponym_view AS CTV
WHERE CTV."districtID" = :districtID
OFFSET :offset
LIMIT :limit
`
Expand All @@ -82,12 +63,10 @@ const commonToponymPageQuery = `
// and includes a buffer operation with a distance of 50 units and specific parameters for joining and capping.
const addressPageQuery = `
SELECT
A.*,
ST_Transform(ST_Buffer(ST_Transform(ST_Envelope(ST_SetSRID(ST_GeomFromGeoJSON((A.positions[1])->'geometry'), 4326)), 2154), :bboxBuffer, 'join=mitre endcap=square'), 4326) AS bbox
AV.*
FROM
ban.address AS A
WHERE A."districtID" = :districtID AND A."isActive" = true
ORDER BY A.id ASC
ban.address_view AS AV
WHERE AV."districtID" = :districtID
OFFSET :offset
LIMIT :limit
`
Expand Down Expand Up @@ -127,12 +106,17 @@ export default async function exportToExploitationDB({data}) {
const commonToponymIDFantoirCodeMap = new Map()

// Map to store the common toponym ID for each legacy common toponym ID to then be able to associate it to the legacy address
const commonToponymIDlegacyCommonToponymIDMap = new Map()
const commonToponymLegacyIDCommonToponymIDMap = new Map()

// Set to store the legacy common toponym ID to avoid duplicates
const commonToponymLegacyIDSet = new Set()

// Set to store the legacy address ID to avoid duplicates
const addressLegacyIDSet = new Set()

// Clean collections
// Delete all data related to the district (legacy and banID)
await deleteAllLegacyDataRelatedToCOG(cog)
await deleteAllDataRelatedToDistrict(districtID)

// CommonToponym
// Count the total number of common toponyms and pages to process
Expand All @@ -152,20 +136,16 @@ export default async function exportToExploitationDB({data}) {
replacements: {
districtID,
offset,
limit: PAGE_SIZE,
addressBboxBuffer: COMMON_TOPONYM_BBOX_BUFFER,
bboxBuffer: SPECIFIC_COMMON_TOPONYM_BBOX_BUFFER},
limit: PAGE_SIZE},
transaction,
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 formatedPageData = pageDataWithExtraDataCalculation.map(commonToponym => formatCommonToponym(commonToponym))
const formatedPageDataForLegacy = pageDataWithExtraDataCalculation.map(commonToponym => formatCommonToponymDataForLegacy(commonToponym, district, pseudoCodeVoieGenerator, commonToponymIDlegacyCommonToponymIDMap))
const formatedPageDataForLegacy = pageDataWithExtraDataCalculation.map(commonToponym => formatCommonToponymDataForLegacy(commonToponym, district, pseudoCodeVoieGenerator, commonToponymLegacyIDCommonToponymIDMap, commonToponymLegacyIDSet))

// Insert the data in the collection (legacy and banID)
await mongo.db.collection(EXPLOITATION_DB_COLLECTION_NAMES.legacy.commonToponym).insertMany(formatedPageDataForLegacy, {ordered: false})
await mongo.db.collection(EXPLOITATION_DB_COLLECTION_NAMES.banID.commonToponym).insertMany(formatedPageData, {ordered: false})
await mongo.db.collection(EXPLOITATION_DB_COLLECTION_NAMES.commonToponym).insertMany(formatedPageDataForLegacy, {ordered: false})
}

const commonToponymsExportPromises = []
Expand All @@ -192,20 +172,17 @@ export default async function exportToExploitationDB({data}) {
replacements: {
districtID,
offset,
limit: PAGE_SIZE,
bboxBuffer: ADDRESS_BBOX_BUFFER},
limit: PAGE_SIZE},
transaction,
raw: true,
})

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

// Insert the data in the collection (legacy and banID)
await mongo.db.collection(EXPLOITATION_DB_COLLECTION_NAMES.legacy.address).insertMany(formatedPageDataForLegacy, {ordered: false})
await mongo.db.collection(EXPLOITATION_DB_COLLECTION_NAMES.banID.address).insertMany(formatedPageData, {ordered: false})
await mongo.db.collection(EXPLOITATION_DB_COLLECTION_NAMES.address).insertMany(formatedPageDataForLegacy, {ordered: false})
}

const addressesExportPromises = []
Expand All @@ -218,10 +195,7 @@ export default async function exportToExploitationDB({data}) {
// District
// For Legacy collections
const districtFormatedForLegacy = await formatDistrictDataForLegacy(district, totalCommonToponymRecords, totalAddressRecords, transaction)
await mongo.db.collection(EXPLOITATION_DB_COLLECTION_NAMES.legacy.district).insertOne(districtFormatedForLegacy)

// For BanID collections
await mongo.db.collection(EXPLOITATION_DB_COLLECTION_NAMES.banID.district).insertOne(district)
await mongo.db.collection(EXPLOITATION_DB_COLLECTION_NAMES.district).updateOne({codeCommune: cog}, {$set: districtFormatedForLegacy}, {upsert: true})

// Pseudo code voie generator saving data
await pseudoCodeVoieGenerator.save()
Expand All @@ -238,37 +212,14 @@ export default async function exportToExploitationDB({data}) {
// Helpers

// Helpers for exploitation DB
const deleteAllDataRelatedToDistrict = async districtID => {
await Promise.all([
mongo.db.collection(EXPLOITATION_DB_COLLECTION_NAMES.banID.district).deleteOne({districtID}),
mongo.db.collection(EXPLOITATION_DB_COLLECTION_NAMES.banID.commonToponym).deleteMany({districtID}),
mongo.db.collection(EXPLOITATION_DB_COLLECTION_NAMES.banID.address).deleteMany({districtID})
])
}

const deleteAllLegacyDataRelatedToCOG = async cog => {
await Promise.all([
mongo.db.collection(EXPLOITATION_DB_COLLECTION_NAMES.legacy.district).deleteOne({codeCommune: cog}),
mongo.db.collection(EXPLOITATION_DB_COLLECTION_NAMES.legacy.commonToponym).deleteMany({codeCommune: cog}),
mongo.db.collection(EXPLOITATION_DB_COLLECTION_NAMES.legacy.address).deleteMany({codeCommune: cog}),
mongo.db.collection(EXPLOITATION_DB_COLLECTION_NAMES.commonToponym).deleteMany({codeCommune: cog}),
mongo.db.collection(EXPLOITATION_DB_COLLECTION_NAMES.address).deleteMany({codeCommune: cog}),
])
}

// Helpers for formatting data
export const formatCommonToponym = commonToponym => {
// To-do : define the format for the common toponym
// For now, we remove data calculation used for the legacy format (centroid, addressCount, certifiedAddressCount, bbox)
const {centroid, addressCount, certifiedAddressCount, addressBbox, bbox, ...rest} = commonToponym
return rest
}

const formatAddress = address => {
// To-do : define the format for the address
// For now, we remove data calculation used for the legacy format (bbox)
const {bbox, ...rest} = address
return rest
}

// Helpers for calculation
export const calculateExtraDataForCommonToponym = (commonToponym, cog, fantoirFinder, commonToponymIDFantoirCodeMap) => {
// Calculate the fantoir code for each common toponym
Expand Down Expand Up @@ -368,4 +319,4 @@ const calculateAddressTiles = address => {
const {positions} = address
const {tiles, x, y} = derivePositionProps(positions?.[0].geometry, TILES_ZOOM_LEVELS.address.min, TILES_ZOOM_LEVELS.address.max)
return {tiles, x, y}
}
}

0 comments on commit 949c3c9

Please sign in to comment.