Commit 959cd6bf authored by Simantini Shinde's avatar Simantini Shinde
Browse files

Calculated household data for districts with no info

parent a256e7ec
Pipeline #39697 passed with stage
in 1 minute and 34 seconds
......@@ -857,11 +857,11 @@ class JapanDatabase(SpatialiteDatabase):
) AS MappingToDistrictWithNoInfo
WHERE rn < 11
) AS ClosestMappingToDistrictWithNoInfo
INNER JOIN BuildingNumber
ON ClosestMappingToDistrictWithNoInfo.source_id = BuildingNumber.district_id
ORDER BY ClosestMappingToDistrictWithNoInfo.to_update_id
INNER JOIN BuildingNumber
ON ClosestMappingToDistrictWithNoInfo.source_id = BuildingNumber.district_id
ORDER BY ClosestMappingToDistrictWithNoInfo.to_update_id
) AS MappingBuildingExposureToDistrictWithNoInfo
Group by MappingBuildingExposureToDistrictWithNoInfo.to_update_id,
GROUP BY MappingBuildingExposureToDistrictWithNoInfo.to_update_id,
MappingBuildingExposureToDistrictWithNoInfo.building_type_id,
MappingBuildingExposureToDistrictWithNoInfo.construction_material_id,
MappingBuildingExposureToDistrictWithNoInfo.story_number_id
......@@ -1192,11 +1192,11 @@ class JapanDatabase(SpatialiteDatabase):
) AS MappingToDistrictWithNoInfo
WHERE rn < 11
) AS ClosestMappingToDistrictWithNoInfo
INNER JOIN DwellingNumber
ON ClosestMappingToDistrictWithNoInfo.source_id = DwellingNumber.district_id
ORDER BY ClosestMappingToDistrictWithNoInfo.to_update_id
INNER JOIN DwellingNumber
ON ClosestMappingToDistrictWithNoInfo.source_id = DwellingNumber.district_id
ORDER BY ClosestMappingToDistrictWithNoInfo.to_update_id
) AS MappingBuildingExposureToDistrictWithNoInfo
Group by MappingBuildingExposureToDistrictWithNoInfo.to_update_id,
GROUP BY MappingBuildingExposureToDistrictWithNoInfo.to_update_id,
MappingBuildingExposureToDistrictWithNoInfo.building_type_id,
MappingBuildingExposureToDistrictWithNoInfo.construction_material_id,
MappingBuildingExposureToDistrictWithNoInfo.story_number_id
......@@ -1472,6 +1472,173 @@ class JapanDatabase(SpatialiteDatabase):
self.connection.commit()
logger.info("Added HouseholdData for number-of-story types")
def calculate_household_data_district_no_info(self):
"""
Calculates the household numbers and household members for districts that do not
have household information in the household dataset.
The household numbers and household members are calculated in query
`ToUpdateHouseholdData` by multiplying the building numbers for districts with no
building information with a factor of the household numbers and household members
per building as taken from the districts with building numbers closest to the
building numbers of the district with no building information.
The innermost query `DistrictWithNoInformation` initially finds the districts not
present in the HouseholdData table by comparing it to the BuildingNumber and
PopulationDistribution tables. These districts are then mapped to their corresponding
building numbers. This final table is cross-joined with all districts from
PopulationDistribution and BuildingNumber and their corresponding building numbers
from the BuildingNumber (i.e. with building information) table in the query
SourceBuildingNumber.
The next outer query `MappingToDistrictWithNoInfo` calculates the absolute value
of the difference between the building numbers of districts with and without
information and sorts it in ascending order to find the districts with information
which are closest in building numbers to the districts without building information.
The following outer query `ClosestMappingToDistrictWithNoInfo` selects only the
first ten districts from districts in query MappingToDistrictWithNoInfo sorted
by the aforementioned difference.
The next outer query `MappingBuildingExposureToDistrictWithNoInfo` maps the building
attributes and their household numbers and household members from the HouseholdData
table to the districts with no information and calculates the household numbers and
household members for districts with no household information. The mapping is done
on the district_id of the ten closest districts (with information) found in the
query `ClosestMappingToDistrictWithNoInfo`.
The final query `ToUpdateHouseholdData` selects the district_id, building exposure
attributes, household numbers and household members to be inserted into the
HouseholdData table.
"""
sql_statement = """
INSERT INTO HouseholdData
(
district_id,
building_type_id,
construction_material_id,
story_number_id,
tenure_type_id,
dwelling_type_id,
number_household,
number_household_member
)
SELECT ToUpdateHouseholdData.to_update_id,
ToUpdateHouseholdData.building_type_id,
ToUpdateHouseholdData.construction_material_id,
ToUpdateHouseholdData.story_number_id,
ToUpdateHouseholdData.tenure_type_id,
ToUpdateHouseholdData.dwelling_type_id,
ToUpdateHouseholdData.to_update_number_household,
ToUpdateHouseholdData.to_update_number_household_member
FROM
(
SELECT MappingBuildingExposureToDistrictWithNoInfo.to_update_id,
MappingBuildingExposureToDistrictWithNoInfo.source_id,
MappingBuildingExposureToDistrictWithNoInfo.building_type_id,
MappingBuildingExposureToDistrictWithNoInfo.construction_material_id,
MappingBuildingExposureToDistrictWithNoInfo.story_number_id,
MappingBuildingExposureToDistrictWithNoInfo.tenure_type_id,
MappingBuildingExposureToDistrictWithNoInfo.dwelling_type_id,
sum(MappingBuildingExposureToDistrictWithNoInfo.number_household),
AVG(MappingBuildingExposureToDistrictWithNoInfo.number_household/
MappingBuildingExposureToDistrictWithNoInfo.source_number_building)
* MappingBuildingExposureToDistrictWithNoInfo.to_update_number_building
AS to_update_number_household,
sum(MappingBuildingExposureToDistrictWithNoInfo.number_household_member),
AVG(MappingBuildingExposureToDistrictWithNoInfo.number_household_member/
MappingBuildingExposureToDistrictWithNoInfo.source_number_building)
* MappingBuildingExposureToDistrictWithNoInfo.to_update_number_building
AS to_update_number_household_member
FROM
(
SELECT *
FROM
(
SELECT MappingToDistrictWithNoInfo.to_update_id,
MappingToDistrictWithNoInfo.source_id,
MappingToDistrictWithNoInfo.rn,
MappingToDistrictWithNoInfo.to_update_number_building,
MappingToDistrictWithNoInfo.source_number_building
FROM
(
SELECT DistrictWithNoInformation.to_update_id,
DistrictWithNoInformation.source_id,
row_number() OVER (
PARTITION BY DistrictWithNoInformation.to_update_id
) AS rn,
DistrictWithNoInformation.to_update_number_building,
DistrictWithNoInformation.source_number_building
FROM
(
SELECT B.district_id AS to_update_id,
B.number_building AS to_update_number_building,
SourceBuildingNumber.district_id AS source_id,
SourceBuildingNumber.number_building
AS source_number_building,
ABS(B.number_building -
SourceBuildingNumber.number_building) AS difference
FROM BuildingNumber AS B
INNER JOIN PopulationDistribution AS PD
ON B.district_id = PD.district_id
CROSS JOIN
(
SELECT BN.district_id, BN.number_building,
BN.building_type_id, BN.construction_material_id,
BN.story_number_id
FROM BuildingNumber AS BN
INNER JOIN
(
SELECT DISTINCT district_id
FROM HouseholdData
) AS HD
ON BN.district_id = HD.district_id
INNER JOIN PopulationDistribution AS PD
ON PD.district_id = HD.district_id
WHERE BN.building_type_id = 0
AND BN.construction_material_id = 0
AND BN.story_number_id = 0
) AS SourceBuildingNumber
WHERE B.district_id NOT IN
(
SELECT district_id
FROM HouseholdData
)
AND B.building_type_id = 0
AND B.construction_material_id = 0
AND B.story_number_id = 0
ORDER BY B.district_id, difference ASC
) AS DistrictWithNoInformation
) AS MappingToDistrictWithNoInfo
WHERE rn < 11
) AS ClosestMappingToDistrictWithNoInfo
INNER JOIN
(
SELECT district_id, building_type_id,
construction_material_id, story_number_id,
tenure_type_id, dwelling_type_id,
number_household, number_household_member
FROM HouseholdData
WHERE tenure_type_id = 0
AND dwelling_type_id = 0
) AS H
ON ClosestMappingToDistrictWithNoInfo.source_id = H.district_id
ORDER BY ClosestMappingToDistrictWithNoInfo.to_update_id
) AS MappingBuildingExposureToDistrictWithNoInfo
GROUP BY MappingBuildingExposureToDistrictWithNoInfo.to_update_id,
MappingBuildingExposureToDistrictWithNoInfo.building_type_id,
MappingBuildingExposureToDistrictWithNoInfo.construction_material_id,
MappingBuildingExposureToDistrictWithNoInfo.story_number_id
) AS ToUpdateHouseholdData
"""
logger.debug(sql_statement)
self.cursor.execute(sql_statement)
self.connection.commit()
logger.info(
"Added household data for districts with no information in HouseholdData table"
)
def import_floorspace_and_dwelling_sizes(
self,
dwelling_sizes_filepath,
......@@ -1732,6 +1899,9 @@ class JapanDatabase(SpatialiteDatabase):
# story types
self.calculate_household_data_for_story_number()
# Calculate the household data for districts with no household information
self.calculate_household_data_district_no_info()
# Import dwelling floorspace and number of dwellings for
# dwelling sizes types into the database
self.import_floorspace_and_dwelling_sizes(
......
Supports Markdown
0% or .
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment