Skip to content

Commit

Permalink
Merge pull request #436 from BaseAdresseNationale/Jugurtha/Initialise…
Browse files Browse the repository at this point in the history
…r-les-vues-dadresses-et-de-toponymes-communs

Initialiser les vues d adresses et de toponymes communs
  • Loading branch information
jbouhadoun authored Jun 24, 2024
2 parents e212698 + 50d5461 commit 6b3c672
Show file tree
Hide file tree
Showing 3 changed files with 91 additions and 43 deletions.
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.log(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/20240618155829-init-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 = 50
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)
}
}
}
52 changes: 9 additions & 43 deletions lib/api/consumers/export-to-exploitation-db-consumer.js
Original file line number Diff line number Diff line change
Expand Up @@ -28,59 +28,29 @@ const TILES_ZOOM_LEVELS = {
}
}

// The buffer distance to use for the bbox calculation
const COMMON_TOPONYM_BBOX_BUFFER = 200
// For specific common toponyms (='lieu-dit'), we use a different buffer distance
const SPECIFIC_COMMON_TOPONYM_BBOX_BUFFER = 100
const ADDRESS_BBOX_BUFFER = 50

// Collections names
const EXPLOITATION_DB_COLLECTION_NAMES = {
district: 'communes',
commonToponym: 'voies',
address: 'numeros'
}

// QUERIES & POSTGIS FUNCTIONS
// The queries are written in raw SQL to be able to use the PostGIS functions
// centroid: It calculates the centroid of a collection of geometries extracted from the "positions" column in the "address" table.
// bbox: It calculates a bounding box (envelope) for a collection of geometries from the "positions" column in the "address" table.
// The bbox result is transformed to a different coordinate system (2154 to 4326) and includes a buffer operation.

// QUERIES
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
`

// The queries are written in raw SQL to be able to use the PostGIS functions
// bbox: It calculates a bounding box (envelope) for the geometry contained in the "positions" column.
// The result is transformed from one coordinate system (2154) to another (4326)
// 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,7 +97,6 @@ export default async function exportToExploitationDB({data}) {

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

// Check if the district has data to export
// To-fix: use the district configuration instead to check if the district has to be exported
const totalCommonToponymRecords = await CommonToponym.count({
Expand Down Expand Up @@ -158,9 +127,7 @@ 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,
})
Expand Down Expand Up @@ -196,8 +163,7 @@ export default async function exportToExploitationDB({data}) {
replacements: {
districtID,
offset,
limit: PAGE_SIZE,
bboxBuffer: ADDRESS_BBOX_BUFFER},
limit: PAGE_SIZE},
transaction,
raw: true,
})
Expand Down

0 comments on commit 6b3c672

Please sign in to comment.