diff --git a/backend-external/src/v1/routes/pay-transparency-routes.ts b/backend-external/src/v1/routes/pay-transparency-routes.ts index 0c0e5c3aa..9654486fe 100644 --- a/backend-external/src/v1/routes/pay-transparency-routes.ts +++ b/backend-external/src/v1/routes/pay-transparency-routes.ts @@ -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 @@ -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: diff --git a/backend/db/migrations/V1.0.24__add_reports_views.sql b/backend/db/migrations/V1.0.24__add_reports_views.sql new file mode 100644 index 000000000..3344f333f --- /dev/null +++ b/backend/db/migrations/V1.0.24__add_reports_views.sql @@ -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; + + \ No newline at end of file diff --git a/backend/src/v1/prisma/prisma-client-readonly-replica.ts b/backend/src/v1/prisma/prisma-client-readonly-replica.ts index 9591b3826..a7190768f 100644 --- a/backend/src/v1/prisma/prisma-client-readonly-replica.ts +++ b/backend/src/v1/prisma/prisma-client-readonly-replica.ts @@ -24,6 +24,6 @@ const prismaReadOnlyReplica = prisma.$extends( readReplicas({ url: readReplicaUrl }), -); +) export default prismaReadOnlyReplica; diff --git a/backend/src/v1/prisma/schema.prisma b/backend/src/v1/prisma/schema.prisma index dc8e4bc96..4e3f3a9c1 100644 --- a/backend/src/v1/prisma/schema.prisma +++ b/backend/src/v1/prisma/schema.prisma @@ -1,6 +1,6 @@ generator client { provider = "prisma-client-js" - previewFeatures = ["metrics"] + previewFeatures = ["metrics", "views"] } datasource db { @@ -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]) +} diff --git a/backend/src/v1/prisma/views/pay_transparency/calculated_data_view.sql b/backend/src/v1/prisma/views/pay_transparency/calculated_data_view.sql new file mode 100644 index 000000000..344a2a101 --- /dev/null +++ b/backend/src/v1/prisma/views/pay_transparency/calculated_data_view.sql @@ -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 + ) + ) + ); \ No newline at end of file diff --git a/backend/src/v1/prisma/views/pay_transparency/reports_view.sql b/backend/src/v1/prisma/views/pay_transparency/reports_view.sql new file mode 100644 index 000000000..37cd58a3e --- /dev/null +++ b/backend/src/v1/prisma/views/pay_transparency/reports_view.sql @@ -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); \ No newline at end of file diff --git a/backend/src/v1/routes/external-consumer-routes.spec.ts b/backend/src/v1/routes/external-consumer-routes.spec.ts index 0a16b151d..00de10a24 100644 --- a/backend/src/v1/routes/external-consumer-routes.spec.ts +++ b/backend/src/v1/routes/external-consumer-routes.spec.ts @@ -4,14 +4,17 @@ import router from './external-consumer-routes'; import { faker } from '@faker-js/faker'; const mockCount = jest.fn(); -const mockQueryRaw = jest.fn(); +const mockReportsViewFindMany = jest.fn(); jest.mock('../prisma/prisma-client-readonly-replica', () => { return { __esModule: true, default: { $replica: () => { return { - $queryRaw: (...args) => mockQueryRaw(...args), + reports_view: { + count: (...args) => mockCount(...args), + findMany: (...args) => mockReportsViewFindMany(...args), + }, }; }, }, @@ -32,20 +35,23 @@ const REPORT = { report_end_date: faker.date.past(), report_status: 'Published', company_name: faker.company.name(), - province: faker.location.state(), - bceid_business_guid: faker.string.uuid(), - country: faker.location.country(), - city: faker.location.city(), - postal_code: faker.location.zipCode(), - address_line1: faker.location.streetAddress(), - address_line2: faker.location.streetAddress(), + company_province: faker.location.state(), + company_bceid_business_guid: faker.string.uuid(), + company_country: faker.location.country(), + company_city: faker.location.city(), + company_postal_code: faker.location.zipCode(), + company_address_line1: faker.location.streetAddress(), + company_address_line2: faker.location.streetAddress(), employee_count_range: '50-299', - naics_label: faker.lorem.words(3), - - value: faker.number.float(), - is_suppressed: false, - calculation_code: faker.number.int(), + naics_code_label: faker.lorem.words(3), + calculated_data: [ + { + value: faker.number.float(), + is_suppressed: false, + calculation_code: faker.number.int(), + }, + ], }; describe('external-consumer-routes', () => { @@ -58,7 +64,7 @@ describe('external-consumer-routes', () => { describe('/ GET', () => { it('should return data if user doeas not send query params', () => { mockCount.mockReturnValue(1); - mockQueryRaw.mockReturnValue([REPORT]); + mockReportsViewFindMany.mockReturnValue([REPORT]); return request(app) .get('') .expect(200) @@ -66,38 +72,31 @@ describe('external-consumer-routes', () => { expect(body).toEqual({ page: 0, pageSize: 50, + totalRecords: 1, records: [ { calculated_data: [ { calculation_code: - REPORT.calculation_code, - is_suppressed: - REPORT.is_suppressed, - value: REPORT.value, + REPORT.calculated_data[0].calculation_code, + is_suppressed: REPORT.calculated_data[0].is_suppressed, + value: REPORT.calculated_data[0].value, }, ], - company_address_line1: - REPORT.address_line1, - company_address_line2: - REPORT.address_line2, - company_bceid_business_guid: - REPORT.bceid_business_guid, - company_city: REPORT.city, - company_country: REPORT.country, + company_address_line1: REPORT.company_address_line1, + company_address_line2: REPORT.company_address_line2, + company_bceid_business_guid: REPORT.company_bceid_business_guid, + company_city: REPORT.company_city, + company_country: REPORT.company_country, company_id: REPORT.company_id, company_name: REPORT.company_name, - company_postal_code: - REPORT.postal_code, - company_province: REPORT.province, + company_postal_code: REPORT.company_postal_code, + company_province: REPORT.company_province, create_date: REPORT.create_date.toISOString(), data_constraints: REPORT.data_constraints, - employee_count_range: - REPORT.employee_count_range, - naics_code: - REPORT.naics_code, - naics_code_label: - REPORT.naics_label, + employee_count_range: REPORT.employee_count_range, + naics_code: REPORT.naics_code, + naics_code_label: REPORT.naics_code_label, report_end_date: REPORT.report_end_date.toISOString(), report_id: REPORT.report_id, report_start_date: REPORT.report_start_date.toISOString(), @@ -122,7 +121,7 @@ describe('external-consumer-routes', () => { }); }); it('should fail if request fails to get reports', () => { - mockQueryRaw.mockRejectedValue({}); + mockReportsViewFindMany.mockRejectedValue({}); return request(app).get('').expect(200); }); }); diff --git a/backend/src/v1/services/external-consumer-service.spec.ts b/backend/src/v1/services/external-consumer-service.spec.ts index 6487bdeff..b76bf8d23 100644 --- a/backend/src/v1/services/external-consumer-service.spec.ts +++ b/backend/src/v1/services/external-consumer-service.spec.ts @@ -1,14 +1,18 @@ import { faker } from '@faker-js/faker'; import { externalConsumerService } from './external-consumer-service'; -const mockQueryRaw = jest.fn(); +const mockReportsViewFindMany = jest.fn(); +const mockReportsViewCount = jest.fn(); jest.mock('../prisma/prisma-client-readonly-replica', () => { return { __esModule: true, default: { $replica: () => { return { - $queryRaw: (...args) => mockQueryRaw(...args), + reports_view: { + count: (...args) => mockReportsViewCount(...args), + findMany: (...args) => mockReportsViewFindMany(...args), + }, }; }, }, @@ -29,18 +33,22 @@ const testData = { report_status: 'Published', reporting_year: 2024, company_name: faker.company.name(), - province: faker.location.state(), - bceid_business_guid: faker.string.uuid(), - country: faker.location.country(), - city: faker.location.city(), - postal_code: faker.location.zipCode(), - address_line1: faker.location.streetAddress(), - address_line2: faker.location.streetAddress(), + company_province: faker.location.state(), + company_bceid_business_guid: faker.string.uuid(), + company_country: faker.location.country(), + company_city: faker.location.city(), + company_postal_code: faker.location.zipCode(), + company_address_line1: faker.location.streetAddress(), + company_address_line2: faker.location.streetAddress(), employee_count_range: '50-299', - naics_label: faker.lorem.words(3), - value: faker.number.float(), - is_suppressed: false, - calculation_code: faker.number.int() + naics_code_label: faker.lorem.words(3), + calculated_data: [ + { + value: faker.number.float(), + is_suppressed: false, + calculation_code: faker.number.int(), + }, + ], }; describe('external-consumer-service', () => { @@ -49,38 +57,31 @@ describe('external-consumer-service', () => { }); it('should return reports with defaults values', async () => { - mockQueryRaw.mockReturnValue([testData]); + mockReportsViewFindMany.mockReturnValue([testData]); const results = await externalConsumerService.exportDataWithPagination(); expect(results.page).toBe(0); expect(results.records[0]).toStrictEqual({ calculated_data: [ { - is_suppressed: - testData.is_suppressed, - value: testData.value, - calculation_code: - testData.calculation_code, + is_suppressed: testData.calculated_data[0].is_suppressed, + value: testData.calculated_data[0].value, + calculation_code: testData.calculated_data[0].calculation_code, }, ], - company_address_line1: testData.address_line1, - company_address_line2: testData.address_line2, - company_bceid_business_guid: - testData.bceid_business_guid, - company_city: testData.city, - company_country: testData.country, + company_address_line1: testData.company_address_line1, + company_address_line2: testData.company_address_line2, + company_bceid_business_guid: testData.company_bceid_business_guid, + company_city: testData.company_city, + company_country: testData.company_country, company_id: testData.company_id, company_name: testData.company_name, - company_postal_code: testData.postal_code, - company_province: testData.province, + company_postal_code: testData.company_postal_code, + company_province: testData.company_province, create_date: testData.create_date, data_constraints: testData.data_constraints, employee_count_range: testData.employee_count_range, - naics_code: - testData - .naics_code, - naics_code_label: - testData - .naics_label, + naics_code: testData.naics_code, + naics_code_label: testData.naics_code_label, report_end_date: testData.report_end_date, report_id: testData.report_id, report_start_date: testData.report_start_date, @@ -93,7 +94,7 @@ describe('external-consumer-service', () => { }); it('should parse date strings', async () => { - mockQueryRaw.mockReturnValue([testData]); + mockReportsViewFindMany.mockReturnValue([testData]); const results = await externalConsumerService.exportDataWithPagination( '2024-01-01', '2024-01-01', @@ -104,7 +105,7 @@ describe('external-consumer-service', () => { }); it('should fail parse invalid date strings', async () => { - mockQueryRaw.mockReturnValue([testData]); + mockReportsViewFindMany.mockReturnValue([testData]); try { await externalConsumerService.exportDataWithPagination( '20241-01-01', @@ -119,7 +120,7 @@ describe('external-consumer-service', () => { } }); it('should fail when endDate is before the startDate', async () => { - mockQueryRaw.mockReturnValue([testData]); + mockReportsViewFindMany.mockReturnValue([testData]); try { await externalConsumerService.exportDataWithPagination( '2024-01-01', diff --git a/backend/src/v1/services/external-consumer-service.ts b/backend/src/v1/services/external-consumer-service.ts index 2bfa15790..473aab6d2 100644 --- a/backend/src/v1/services/external-consumer-service.ts +++ b/backend/src/v1/services/external-consumer-service.ts @@ -6,84 +6,9 @@ import { convert, nativeJs, } from '@js-joda/core'; -import groupBy from 'lodash/groupBy'; -import keys from 'lodash/keys'; import { PayTransparencyUserError } from './file-upload-service'; import { Prisma } from '@prisma/client'; -type RawQueryResult = { - report_id: string; - report_change_id: string; - company_id: string; - user_id: string; - user_comment: any; - employee_count_range_id: string; - naics_code: string; - report_start_date: string; - report_end_date: string; - create_date: string; - update_date: string; - create_user: string; - update_user: string; - report_status: string; - revision: number; - data_constraints: any; - is_unlocked: boolean; - reporting_year: number; - report_unlock_date: any; - naics_label: string; - effective_date: string; - expiry_date: any; - naics_year: string; - employee_count_range: string; - calculation_code_id: string; - value: string; - is_suppressed: boolean; - calculation_code: string; - company_name: string; - province: string; - bceid_business_guid: string; - city: string; - country: string; - postal_code: string; - address_line1: string; - address_line2: string; -}; - -const buildReport = (data: RawQueryResult[]) => { - const first = data[0]; - - return { - report_id: first.report_id, - company_id: first.company_id, - naics_code: first.naics_code, - create_date: first.create_date, - update_date: first.update_date, - data_constraints: first.data_constraints, - user_comment: first.user_comment, - revision: first.revision, - report_start_date: first.report_start_date, - report_end_date: first.report_end_date, - report_status: first.report_status, - reporting_year: first.reporting_year, - company_name: first.company_name, - company_province: first.province, - company_bceid_business_guid: first.bceid_business_guid, - company_city: first.city, - company_country: first.country, - company_postal_code: first.postal_code, - company_address_line1: first.address_line1, - company_address_line2: first.address_line2, - employee_count_range: first.employee_count_range, - naics_code_label: first.naics_label, - calculated_data: data.map((item) => ({ - value: item.value, - is_suppressed: item.is_suppressed, - calculation_code: item.calculation_code, - })), - }; -}; - const DEFAULT_PAGE_SIZE = 50; const externalConsumerService = { @@ -147,134 +72,60 @@ const externalConsumerService = { ); } + const whereClause: Prisma.reports_viewWhereInput = { + update_date: { + gte: convert(startDt).toDate(), + lt: convert(endDt).toDate(), + }, + }; + /** - * 1) Create a union of the pay_transparency_report and report_history table as reports - * 2) Sort by update date, then by revision (have to sort by revision too because reports in version PT1.2 all share the same update date ) - * 3) Create a union of the pay_transparency_calculated_data and calculated_data_history as calculated - * 4) Paginate the reports - * 5) Join reports and calculated_data based on report_change_id + * Querying the reports and their data uses 2 sql views (reports_view, calculated_data_view) that + * are included in the Prisma schema by enabling views feature and running a db pull. The 2 views in the + * schema were modified to add unique columns keys and relations between the projects_view and the calculated_data_view + * + * + * The prisma views + * is still in preview and we must monitor its status to mitigate risk using the following links: + * 1) https://www.prisma.io/docs/orm/prisma-schema/data-model/views + * 2) https://github.com/prisma/prisma/issues/17335 + * + * The views are added to the database using a database migration script (V1.0.24__add_reports_views.sql). The */ - const getReportsQuery = Prisma.sql`select * - from ((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.is_unlocked, - report.reporting_year, - report.report_unlock_date, - naics_code.naics_label, - company.company_id, - company.company_name, - company.bceid_business_guid, - company.address_line1, - company.address_line2, - company.city, - company.province, - company.country, - company.postal_code, - employee_count_range.employee_count_range - from pay_transparency_report as report - left join naics_code as naics_code on naics_code.naics_code = report.naics_code - left join pay_transparency_company as company on company.company_id = report.company_id - left join employee_count_range as employee_count_range on employee_count_range.employee_count_range_id = report.employee_count_range_id - where report_status = 'Published' - and (report.update_date >= ${convert(startDt).toDate()} - and report.update_date < ${convert(endDt).toDate()}) - 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.is_unlocked, - report.reporting_year, - report.report_unlock_date, - naics_code.naics_label, - company.company_id, - company.company_name, - company.bceid_business_guid, - company.address_line1, - company.address_line2, - company.city, - company.province, - company.country, - company.postal_code, - employee_count_range.employee_count_range - from report_history as report - left join naics_code as naics_code on naics_code.naics_code = report.naics_code - left join pay_transparency_company as company on company.company_id = report.company_id - left join employee_count_range as employee_count_range on employee_count_range.employee_count_range_id = report.employee_count_range_id - where report_status = 'Published' - and (report.update_date >= ${convert(startDt).toDate()} - and report.update_date < ${convert(endDt).toDate()}))) - order by update_date, revision - offset ${offset} - limit ${limit}) as reports -left join - (select data.report_id as calculated_data_report_id, - data.calculation_code_id, - data.value, - data.is_suppressed, - code.calculation_code - from - (select data.report_id, - data.calculation_code_id, - data.value, - data.is_suppressed - from pay_transparency_calculated_data as data where data.update_date >= ${convert(startDt).toDate()} - and data.update_date < ${convert(endDt).toDate()} - union - (select data.report_history_id as report_id, - data.calculation_code_id, - data.value, - data.is_suppressed - from calculated_data_history as data where data.update_date >= ${convert(startDt).toDate()} - and data.update_date < ${convert(endDt).toDate()})) as data - left join calculation_code as code on code.calculation_code_id = data.calculation_code_id) as calculated_data on calculated_data.calculated_data_report_id = reports.report_change_id`; - - const results = await prismaReadOnlyReplica + const records = await prismaReadOnlyReplica .$replica() - .$queryRaw(getReportsQuery); - const uniqueReports: Record = groupBy( - results, - (x) => x.report_change_id, - ); + .reports_view.findMany({ + where: whereClause, + include: { + calculated_data: { + select: { + value: true, + is_suppressed: true, + calculation_code: true, + }, + }, + }, + take: limit, + skip: offset, + orderBy: [{ update_date: 'asc' }, { revision: 'asc' }], + }); - const uniqueReportIds: string[] = keys(uniqueReports); + const totalRecordsCount = await prismaReadOnlyReplica + .$replica() + .reports_view.count({ + where: whereClause, + }); - const reports = uniqueReportIds.map((id_rev) => { - const data = uniqueReports[id_rev]; - return buildReport(data); - }); + records.forEach(report => { + delete report.report_change_id; + }) return { + totalRecords: totalRecordsCount, page: offset / limit, pageSize: limit, - records: reports, + records, }; }, };