Skip to content

Commit

Permalink
Add back participating population
Browse files Browse the repository at this point in the history
  • Loading branch information
Jacob Harris committed Apr 28, 2017
1 parent a45960b commit 59a5f1c
Show file tree
Hide file tree
Showing 5 changed files with 62 additions and 10 deletions.
18 changes: 18 additions & 0 deletions crime_data/common/cdemodels.py
Original file line number Diff line number Diff line change
Expand Up @@ -153,6 +153,15 @@ def total_population_for_year(self, data_year):
"""Returns the population for a given year"""
return self._participation_for_year(data_year).total_population

@property
def participating_population(self):
"""Returns the population for the given year"""
return self.participating_population_for_year(self.current_year)

def participating_population_for_year(self, data_year):
"""Returns the population for a given year"""
return self._participation_for_year(data_year).participating_population

def police_officers_for_year(self, data_year):
"""Returns the number of police officers for a given year"""
query = session.query(func.sum(models.PeEmployeeData.male_officer +
Expand Down Expand Up @@ -253,6 +262,15 @@ def participating_agencies_for_year(self, data_year):
"""Counts the number of agencies for that county in a year."""
return self._participation_for_year(data_year).participating_agencies

@property
def participating_population(self):
"""Returns the population for the given year"""
return self.participating_population_for_year(self.current_year)

def participating_population_for_year(self, data_year):
"""Returns the population for a given year"""
return self._participation_for_year(data_year).participating_population

@property
def total_agencies(self):
"""Returns the number of agencies for the most recent year"""
Expand Down
1 change: 1 addition & 0 deletions crime_data/common/newmodels.py
Original file line number Diff line number Diff line change
Expand Up @@ -94,6 +94,7 @@ class ParticipationRate(db.Model):
covered_agencies = db.Column(db.Integer)
covered_rate = db.Column(db.Float)
total_population = db.Column(db.BigInteger)
participating_population = db.Column(db.BigInteger)


class CreatableModel:
Expand Down
12 changes: 11 additions & 1 deletion crime_data/static/swagger.json
Original file line number Diff line number Diff line change
Expand Up @@ -877,8 +877,9 @@
"total_agencies",
"participation_rate",
"total_population",
"participating_population",
"nibrs_participating_agencies",
"nibrs_participation_rate",
"nibrs_participation_rate"
],
"prvoperties": {
"year": {
Expand Down Expand Up @@ -914,6 +915,15 @@
],
"minimum": 0
},
"participating_population": {
"description": "The sum of the population within the jurisdictions of all agencies that participated for that year",
"format": "int32",
"type": [
"integer",
"null"
],
"minimum": 0
},
"nibrs_participating_agencies": {
"description": "The number of agencies who filed a NIBRS report in the given year or were covered by another agency that filed NIBRS",
"type": "integer"
Expand Down
39 changes: 31 additions & 8 deletions dba/after_load/participation_table.sql
Original file line number Diff line number Diff line change
Expand Up @@ -77,7 +77,8 @@ CREATE TABLE participation_rates_temp
nibrs_participation_rate float,
covered_agencies int,
covered_rate float,
total_population bigint
total_population bigint,
participating_population bigint
);

ALTER TABLE ONLY participation_rates_temp
Expand All @@ -86,7 +87,7 @@ ADD CONSTRAINT participation_rates_state_fk FOREIGN KEY (state_id) REFERENCES re
ALTER TABLE ONLY participation_rates_temp
ADD CONSTRAINT participation_rates_county_fk FOREIGN KEY (county_id) REFERENCES ref_county(county_id);

INSERT INTO participation_rates_temp(participation_id, year, state_id, state_name, total_agencies, participating_agencies, participation_rate, nibrs_participating_agencies, nibrs_participation_rate, covered_agencies, covered_rate)
INSERT INTO participation_rates_temp(participation_id, year, state_id, state_name, total_agencies, participating_agencies, participation_rate, nibrs_participating_agencies, nibrs_participation_rate, covered_agencies, covered_rate, participating_population)
SELECT
NEXTVAL('retacubeseq') AS participation_id,
c.year,
Expand All @@ -98,7 +99,8 @@ CAST(SUM(c.participated) AS float)/COUNT(a.ORI) AS participation_rate,
SUM(c.nibrs_participated) AS nibrs_participating_agencies,
CAST(SUM(c.nibrs_participated) AS float)/COUNT(a.ORI) AS nibrs_participation_rate,
COUNT(racb.agency_id) AS covered_agencies,
CAST(COUNT(racb.agency_id) AS float)/COUNT(a.ORI) AS covered_rate
CAST(COUNT(racb.agency_id) AS float)/COUNT(a.ORI) AS covered_rate,
0 AS participating_population
FROM agency_participation c
JOIN ref_agency a ON a.agency_id = c.agency_id
JOIN ref_state rs ON a.state_id = rs.state_id
Expand All @@ -109,7 +111,7 @@ GROUP BY c.year, a.state_id, rs.state_name;
-- the total/reporting agencies counts for each county. Its population
-- is apportioned individually though, so its full population won't be
-- duplicated for each county
INSERT INTO participation_rates_temp(participation_id, year, county_id, county_name, total_agencies, participating_agencies, participation_rate, nibrs_participating_agencies, nibrs_participation_rate, total_population, covered_agencies, covered_rate)
INSERT INTO participation_rates_temp(participation_id, year, county_id, county_name, total_agencies, participating_agencies, participation_rate, nibrs_participating_agencies, nibrs_participation_rate, total_population, participating_population, covered_agencies, covered_rate)
SELECT
NEXTVAL('retacubeseq') AS participation_id,
c.year,
Expand All @@ -121,6 +123,7 @@ CAST(SUM(c.participated) AS float)/COUNT(a.ori) AS participation_rate,
SUM(c.nibrs_participated) AS nibrs_participating_agencies,
CAST(SUM(c.nibrs_participated) AS float)/COUNT(a.ori) AS nibrs_participation_rate,
SUM(rac.population) AS total_population,
SUM(CASE WHEN c.participated = 1 THEN rac.population ELSE 0 END) AS participating_population,
COUNT(racb.agency_id) AS covered_agencies,
CAST(COUNT(racb.agency_id) AS float)/COUNT(a.ori) AS covered_rate
FROM agency_participation c
Expand All @@ -131,15 +134,25 @@ LEFT OUTER JOIN ref_agency_covered_by racb ON racb.agency_id=c.agency_id AND rac
GROUP BY c.year, rc.county_id, rc.county_name;

UPDATE participation_rates_temp
SET total_population=(SELECT SUM(rac.population)
SET total_population=(SELECT COALESCE(SUM(rac.population), 0)
FROM ref_agency_county rac
JOIN ref_agency ra ON ra.agency_id=rac.agency_id
WHERE ra.state_id=participation_rates_temp.state_id
AND rac.data_year=participation_rates_temp.year)
WHERE state_id IS NOT NULL;

UPDATE participation_rates_temp
SET participating_population=(SELECT COALESCE(SUM(rac.population), 0)
FROM ref_agency_county rac
JOIN ref_agency ra ON ra.agency_id=rac.agency_id
JOIN agency_participation c ON c.agency_id=ra.agency_id AND c.year=rac.data_year
WHERE ra.state_id=participation_rates_temp.state_id
AND rac.data_year=participation_rates_temp.year
AND c.participated = 1)
WHERE state_id IS NOT NULL;

--- annual rollups
INSERT INTO participation_rates_temp(participation_id, year, total_agencies, participating_agencies, participation_rate, nibrs_participating_agencies, nibrs_participation_rate, covered_agencies, covered_rate)
INSERT INTO participation_rates_temp(participation_id, year, total_agencies, participating_agencies, participation_rate, nibrs_participating_agencies, nibrs_participation_rate, covered_agencies, covered_rate, participating_population)
SELECT
NEXTVAL('retacubeseq') AS participation_id,
c.year,
Expand All @@ -149,18 +162,28 @@ CAST(SUM(c.participated) AS float)/COUNT(a.ORI) AS participation_rate,
SUM(c.nibrs_participated) AS nibrs_participating_agencies,
CAST(SUM(c.nibrs_participated) AS float)/COUNT(a.ORI) AS nibrs_participation_rate,
COUNT(racb.agency_id) as covered_agencies,
CAST(COUNT(racb.agency_id) AS float)/COUNT(a.ORI) AS covered_rate
CAST(COUNT(racb.agency_id) AS float)/COUNT(a.ORI) AS covered_rate,
0 as participation_population
FROM agency_participation c
JOIN ref_agency a ON a.agency_id = c.agency_id
LEFT OUTER JOIN ref_agency_covered_by racb ON racb.agency_id=c.agency_id AND racb.data_year=c.year
GROUP BY c.year;

UPDATE participation_rates_temp
SET total_population=(SELECT SUM(rac.population)
SET total_population=(SELECT COALESCE(SUM(rac.population), 0)
FROM ref_agency_county rac
JOIN ref_agency ra ON ra.agency_id=rac.agency_id
WHERE rac.data_year=participation_rates_temp.year)
WHERE state_id IS NULL AND county_id IS NULL;

UPDATE participation_rates_temp
SET participating_population=(SELECT COALESCE(SUM(rac.population), 0)
FROM ref_agency_county rac
JOIN ref_agency ra ON ra.agency_id=rac.agency_id
JOIN agency_participation c ON c.agency_id=rac.agency_id AND c.year=rac.data_year
WHERE rac.data_year=participation_rates_temp.year
AND c.participated=1)
WHERE state_id IS NULL AND county_id IS NULL;

DROP TABLE IF EXISTS participation_rates CASCADE;
ALTER TABLE participation_rates_temp RENAME TO participation_rates;
2 changes: 1 addition & 1 deletion tests/unit/test_cdemodels.py
Original file line number Diff line number Diff line change
Expand Up @@ -124,7 +124,7 @@ def test_participation(self, app):
# WHERE rm.reported_flag = 'Y'
# AND rm.data_year=rac.data_year
# AND rm.data_year=1960 and ra.state_id=55)
# assert state.covered_population_for_year(test_year) == 177770
assert state.participating_population_for_year(test_year) == 0

def test_participation_cache_is_not_global(self, app):
test_year = 1960
Expand Down

0 comments on commit 59a5f1c

Please sign in to comment.