Skip to content

Commit

Permalink
fix: get reports api performance tuning (#499)
Browse files Browse the repository at this point in the history
  • Loading branch information
goemen authored May 24, 2024
1 parent 1a9778f commit 12d658c
Show file tree
Hide file tree
Showing 9 changed files with 406 additions and 270 deletions.
7 changes: 5 additions & 2 deletions backend-external/src/v1/routes/pay-transparency-routes.ts
Original file line number Diff line number Diff line change
Expand Up @@ -77,6 +77,9 @@ const router = express.Router();
* PaginatedReports:
* type: object
* properties:
* totalRecords:
* type: number
* description: total number of records in the database
* page:
* type: number
* description: Current page offset
Expand Down Expand Up @@ -120,13 +123,13 @@ const router = express.Router();
* type: date
* pattern: /([0-9]{4})-(?:[0-9]{2})-([0-9]{2})/
* required: false
* description: "Start date for the update date range filter (format: YYYY-MM-dd) - optional"
* description: "Start date in UTC for the update date range filter (format: YYYY-MM-dd) - optional"
* - in: query
* name: endDate
* type: string
* pattern: /([0-9]{4})-(?:[0-9]{2})-([0-9]{2})/
* required: false
* description: "End date for the update date range filter (format: YYYY-MM-dd) - optional"
* description: "End date in UTC for the update date range filter (format: YYYY-MM-dd) - optional"
*
*
* responses:
Expand Down
105 changes: 105 additions & 0 deletions backend/db/migrations/V1.0.24__add_reports_views.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,105 @@
SET search_path TO pay_transparency;

--- Follow this link to learn about views and Prisma
--- https://www.prisma.io/docs/orm/prisma-schema/data-model/views

CREATE OR REPLACE VIEW reports_view
AS
SELECT
report.report_id,
report.report_id AS report_change_id,
report.company_id,
report.user_id,
report.user_comment,
report.employee_count_range_id,
report.naics_code,
report.report_start_date,
report.report_end_date,
report.create_date,
report.update_date,
report.create_user,
report.update_user,
report.report_status,
report.revision,
report.data_constraints,
report.reporting_year,
report.report_unlock_date,
naics_code.naics_label as naics_code_label,
company.company_name,
company.bceid_business_guid as company_bceid_business_guid,
company.address_line1 as company_address_line1,
company.address_line2 as company_address_line2,
company.city as company_city,
company.province as company_province,
company.country as company_country,
company.postal_code as company_postal_code,
employee_count_range.employee_count_range
FROM pay_transparency.pay_transparency_report report
LEFT JOIN pay_transparency.naics_code naics_code ON naics_code.naics_code::text = report.naics_code::text
LEFT JOIN pay_transparency.pay_transparency_company company ON company.company_id = report.company_id
LEFT JOIN pay_transparency.employee_count_range employee_count_range ON employee_count_range.employee_count_range_id = report.employee_count_range_id
WHERE report.report_status::text = 'Published'::text
UNION
SELECT
report.report_id,
report.report_history_id AS report_change_id,
report.company_id,
report.user_id,
report.user_comment,
report.employee_count_range_id,
report.naics_code,
report.report_start_date,
report.report_end_date,
report.create_date,
report.update_date,
report.create_user,
report.update_user,
report.report_status,
report.revision,
report.data_constraints,
report.reporting_year,
report.report_unlock_date,
naics_code.naics_label as naics_code_label,
company.company_name,
company.bceid_business_guid as company_bceid_business_guid,
company.address_line1 as company_address_line1,
company.address_line2 as company_address_line2,
company.city as company_city,
company.province as company_province,
company.country as company_country,
company.postal_code as company_postal_code,
employee_count_range.employee_count_range
FROM pay_transparency.report_history report
LEFT JOIN pay_transparency.naics_code naics_code ON naics_code.naics_code::text = report.naics_code::text
LEFT JOIN pay_transparency.pay_transparency_company company ON company.company_id = report.company_id
LEFT JOIN pay_transparency.employee_count_range employee_count_range ON employee_count_range.employee_count_range_id = report.employee_count_range_id
WHERE report.report_status::text = 'Published'::text;


CREATE OR REPLACE VIEW calculated_data_view
AS
SELECT
data.calculated_data_id,
data.report_id,
data.calculation_code_id,
data.value,
data.is_suppressed,
code.calculation_code
FROM (SELECT
data_1.calculated_data_id,
data_1.report_id,
data_1.calculation_code_id,
data_1.value,
data_1.is_suppressed
FROM pay_transparency.pay_transparency_calculated_data data_1
UNION
SELECT
data_1.calculated_data_history_id as calculated_data_id,
data_1.report_history_id AS report_id,
data_1.calculation_code_id,
data_1.value,
data_1.is_suppressed
FROM pay_transparency.calculated_data_history data_1) data
LEFT JOIN pay_transparency.calculation_code code ON code.calculation_code_id = data.calculation_code_id;


2 changes: 1 addition & 1 deletion backend/src/v1/prisma/prisma-client-readonly-replica.ts
Original file line number Diff line number Diff line change
Expand Up @@ -24,6 +24,6 @@ const prismaReadOnlyReplica = prisma.$extends(
readReplicas({
url: readReplicaUrl
}),
);
)

export default prismaReadOnlyReplica;
44 changes: 43 additions & 1 deletion backend/src/v1/prisma/schema.prisma
Original file line number Diff line number Diff line change
@@ -1,6 +1,6 @@
generator client {
provider = "prisma-client-js"
previewFeatures = ["metrics"]
previewFeatures = ["metrics", "views"]
}

datasource db {
Expand Down Expand Up @@ -208,3 +208,45 @@ model calculated_data_history {
@@unique([report_history_id, calculation_code_id])
}

view reports_view {
report_id String? @db.Uuid
report_change_id String @id @db.Uuid
company_id String? @db.Uuid
user_id String? @db.Uuid
user_comment String? @db.VarChar(4000)
employee_count_range_id String? @db.Uuid
naics_code String? @db.VarChar(5)
report_start_date DateTime? @db.Date
report_end_date DateTime? @db.Date
create_date DateTime? @db.Timestamp(6)
update_date DateTime? @db.Timestamp(6)
create_user String? @db.VarChar(255)
update_user String? @db.VarChar(255)
report_status String? @db.VarChar(255)
revision Decimal? @db.Decimal
data_constraints String? @db.VarChar(3000)
reporting_year Decimal? @db.Decimal
report_unlock_date DateTime? @db.Timestamp(6)
naics_code_label String? @db.VarChar(255)
company_name String? @db.VarChar(255)
company_bceid_business_guid String? @db.Uuid
company_address_line1 String? @db.VarChar(255)
company_address_line2 String? @db.VarChar(255)
company_city String? @db.VarChar(255)
company_province String? @db.VarChar(255)
company_country String? @db.VarChar(255)
company_postal_code String? @db.VarChar(255)
employee_count_range String? @db.VarChar(255)
calculated_data calculated_data_view[]
}

view calculated_data_view {
calculated_data_id String @id @db.Uuid
report_id String @db.Uuid
calculation_code_id String? @db.Uuid
value String? @db.VarChar(50)
is_suppressed Boolean?
calculation_code String? @db.VarChar(255)
report reports_view @relation(fields: [report_id], references: [report_change_id])
}
Original file line number Diff line number Diff line change
@@ -0,0 +1,34 @@
SELECT
data.calculated_data_id,
data.report_id,
data.calculation_code_id,
data.value,
data.is_suppressed,
code.calculation_code
FROM
(
(
SELECT
data_1.calculated_data_id,
data_1.report_id,
data_1.calculation_code_id,
data_1.value,
data_1.is_suppressed
FROM
pay_transparency_calculated_data data_1
UNION
SELECT
data_1.calculated_data_history_id AS calculated_data_id,
data_1.report_history_id AS report_id,
data_1.calculation_code_id,
data_1.value,
data_1.is_suppressed
FROM
calculated_data_history data_1
) data
LEFT JOIN calculation_code code ON (
(
code.calculation_code_id = data.calculation_code_id
)
)
);
101 changes: 101 additions & 0 deletions backend/src/v1/prisma/views/pay_transparency/reports_view.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,101 @@
SELECT
report.report_id,
report.report_id AS report_change_id,
report.company_id,
report.user_id,
report.user_comment,
report.employee_count_range_id,
report.naics_code,
report.report_start_date,
report.report_end_date,
report.create_date,
report.update_date,
report.create_user,
report.update_user,
report.report_status,
report.revision,
report.data_constraints,
report.reporting_year,
report.report_unlock_date,
naics_code.naics_label AS naics_code_label,
company.company_name,
company.bceid_business_guid AS company_bceid_business_guid,
company.address_line1 AS company_address_line1,
company.address_line2 AS company_address_line2,
company.city AS company_city,
company.province AS company_province,
company.country AS company_country,
company.postal_code AS company_postal_code,
employee_count_range.employee_count_range
FROM
(
(
(
pay_transparency_report report
LEFT JOIN naics_code naics_code ON (
(
(naics_code.naics_code) :: text = (report.naics_code) :: text
)
)
)
LEFT JOIN pay_transparency_company company ON ((company.company_id = report.company_id))
)
LEFT JOIN employee_count_range employee_count_range ON (
(
employee_count_range.employee_count_range_id = report.employee_count_range_id
)
)
)
WHERE
((report.report_status) :: text = 'Published' :: text)
UNION
SELECT
report.report_id,
report.report_history_id AS report_change_id,
report.company_id,
report.user_id,
report.user_comment,
report.employee_count_range_id,
report.naics_code,
report.report_start_date,
report.report_end_date,
report.create_date,
report.update_date,
report.create_user,
report.update_user,
report.report_status,
report.revision,
report.data_constraints,
report.reporting_year,
report.report_unlock_date,
naics_code.naics_label AS naics_code_label,
company.company_name,
company.bceid_business_guid AS company_bceid_business_guid,
company.address_line1 AS company_address_line1,
company.address_line2 AS company_address_line2,
company.city AS company_city,
company.province AS company_province,
company.country AS company_country,
company.postal_code AS company_postal_code,
employee_count_range.employee_count_range
FROM
(
(
(
report_history report
LEFT JOIN naics_code naics_code ON (
(
(naics_code.naics_code) :: text = (report.naics_code) :: text
)
)
)
LEFT JOIN pay_transparency_company company ON ((company.company_id = report.company_id))
)
LEFT JOIN employee_count_range employee_count_range ON (
(
employee_count_range.employee_count_range_id = report.employee_count_range_id
)
)
)
WHERE
((report.report_status) :: text = 'Published' :: text);
Loading

0 comments on commit 12d658c

Please sign in to comment.