Skip to content
This repository has been archived by the owner on Feb 1, 2024. It is now read-only.

Commit

Permalink
Merge pull request #1326 from open-apparel-registry/tw/add-new-reports
Browse files Browse the repository at this point in the history
Add new admin reports
  • Loading branch information
TaiWilkin committed May 12, 2021
2 parents 1d0cb7d + 5a4920c commit 5f1dee0
Show file tree
Hide file tree
Showing 6 changed files with 147 additions and 0 deletions.
1 change: 1 addition & 0 deletions CHANGELOG.md
Original file line number Diff line number Diff line change
Expand Up @@ -16,6 +16,7 @@ and this project adheres to [Semantic Versioning](http://semver.org/spec/v2.0.0.
- Add Back Button to Facility Claims [#1307](https://github.com/open-apparel-registry/open-apparel-registry/pull/1307)
- Add models to persist embed config [#1304](https://github.com/open-apparel-registry/open-apparel-registry/pull/1304)
- Add API to get nonstandard fields for contributor [#1321](https://github.com/open-apparel-registry/open-apparel-registry/pull/1321)
- Add new admin reports [#1326](https://github.com/open-apparel-registry/open-apparel-registry/pull/1326)

### Changed

Expand Down
29 changes: 29 additions & 0 deletions src/django/api/reports/average_affiliations.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,29 @@
SELECT
month,
ROUND(AVG(match_count), 2) as average_matches
FROM (
SELECT f.id, COUNT(*) as match_count, zmonth as month
FROM api_facility f
JOIN (
SELECT DISTINCT
c.id,
fm.facility_id,
to_char(fm.created_at, 'YYYY-MM') as created_month,
z.month as zmonth
FROM api_facilitymatch fm
JOIN api_facilitylistitem i
ON fm.facility_list_item_id = i.id
JOIN api_source s
ON i.source_id = s.id
JOIN api_contributor c
ON s.contributor_id = c.id
JOIN (
SELECT to_char(m.created_at, 'YYYY-MM') as month
FROM api_facilitymatch m group by month
) z ON to_char(fm.created_at, 'YYYY-MM') <= z.month
WHERE fm.status NOT IN ('PENDING', 'REJECTED')
) as fm ON f.id = fm.facility_id
GROUP BY zmonth, f.id
) as c
GROUP BY month
ORDER BY month;
22 changes: 22 additions & 0 deletions src/django/api/reports/industry_data_vs_oar_data.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,22 @@
SELECT
fm.month,
ROUND(CAST(
(COUNT(CASE WHEN fm.is_public_list THEN 1 ELSE NULL END)*100)
as decimal)/COUNT(*), 2) AS oar_data,
ROUND(CAST(
(COUNT(CASE WHEN NOT fm.is_public_list THEN 1 ELSE NULL END)*100)
as decimal)/COUNT(*), 2) AS industry_data
FROM (
SELECT
MIN(to_char(m.created_at, 'YYYY-MM')) AS month,
u.email LIKE '%openapparel.org%' AS is_public_list
FROM api_facilitymatch m
JOIN api_facilitylistitem i on m.facility_list_item_id = i.id
JOIN api_source s on i.source_id = s.id
JOIN api_contributor c ON s.contributor_id = c.id
JOIN api_user u ON u.id = c.admin_id
WHERE m.status NOT IN ('REJECTED', 'PENDING')
GROUP BY m.facility_id, u.email
) as fm
GROUP BY fm.month
ORDER BY fm.month
35 changes: 35 additions & 0 deletions src/django/api/reports/percent_data_by_contributor_type.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,35 @@
SELECT
match.month,
contrib_type,
ROUND(CAST((COUNT(*)*100) as decimal)/total, 2) as percent_of_data
FROM (
SELECT
MIN(to_char(m.created_at, 'YYYY-MM')) AS month,
contrib_type
FROM api_facilitymatch m
JOIN api_facilitylistitem i on m.facility_list_item_id = i.id
JOIN api_source s on i.source_id = s.id
JOIN api_contributor c ON s.contributor_id = c.id
JOIN api_user u ON u.id = c.admin_id
WHERE m.status NOT IN ('REJECTED', 'PENDING')
AND u.email NOT LIKE '%openapparel.org%'
GROUP BY m.facility_id, u.email, c.contrib_type
) as match
JOIN (
SELECT month, count(*) as total
FROM (
SELECT
MIN(to_char(m.created_at, 'YYYY-MM')) AS month
FROM api_facilitymatch m
JOIN api_facilitylistitem i on m.facility_list_item_id = i.id
JOIN api_source s on i.source_id = s.id
JOIN api_contributor c ON s.contributor_id = c.id
JOIN api_user u ON u.id = c.admin_id
WHERE m.status NOT IN ('REJECTED', 'PENDING')
AND u.email NOT LIKE '%openapparel.org%'
GROUP BY m.facility_id, u.email
) as fm
GROUP BY month
ORDER BY month
) t ON t.month = match.month
GROUP BY match.month, contrib_type, total;
31 changes: 31 additions & 0 deletions src/django/api/reports/percent_data_by_source_type.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,31 @@
SELECT
match.month,
source_type,
ROUND(CAST((COUNT(*)*100) as decimal)/total, 2) as percent_of_data
FROM (
SELECT
MIN(to_char(m.created_at, 'YYYY-MM')) AS month,
source_type
FROM api_facilitymatch m
JOIN api_facilitylistitem i on m.facility_list_item_id = i.id
JOIN api_source s on i.source_id = s.id
JOIN api_contributor c ON s.contributor_id = c.id
WHERE m.status NOT IN ('REJECTED', 'PENDING')
GROUP BY m.facility_id, c.id, s.source_type
) as match
JOIN (
SELECT month, count(*) as total
FROM (
SELECT
MIN(to_char(m.created_at, 'YYYY-MM')) AS month
FROM api_facilitymatch m
JOIN api_facilitylistitem i on m.facility_list_item_id = i.id
JOIN api_source s on i.source_id = s.id
JOIN api_contributor c ON s.contributor_id = c.id
WHERE m.status NOT IN ('REJECTED', 'PENDING')
GROUP BY m.facility_id, c.id
) as fm
GROUP BY month
ORDER BY month
) t ON t.month = match.month
GROUP BY match.month, source_type, total;
Original file line number Diff line number Diff line change
@@ -0,0 +1,29 @@
SELECT zmonth as month,
ROUND(CAST((facilities_with_multiple_matches*100) as decimal)/total_facilities, 2) as percent_of_data_with_multiple_matches,
facilities_with_multiple_matches,
total_facilities
FROM (
SELECT
zmonth,
COUNT(CASE WHEN match_count > 1 THEN 1 ELSE NULL END) as facilities_with_multiple_matches,
COUNT(*) AS total_facilities
FROM (
SELECT facility_id, COUNT(*) as match_count, zmonth
FROM
(
SELECT
fm.facility_id,
z.month as zmonth
FROM api_facilitymatch fm
JOIN (
SELECT to_char(m.created_at, 'YYYY-MM') as month
FROM api_facilitymatch m group by month
) z ON to_char(fm.created_at, 'YYYY-MM') <= z.month
JOIN api_facilitylistitem i ON i.id = fm.facility_list_item_id
JOIN api_source s on i.source_id = s.id
GROUP BY s.contributor_id, zmonth, fm.facility_id
) as f
GROUP BY f.facility_id, zmonth
) as y
GROUP BY zmonth
) as z

0 comments on commit 5f1dee0

Please sign in to comment.