Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Project/admit IDs query for mobile app #656

Merged
merged 1 commit into from
Dec 15, 2023
Merged
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
62 changes: 62 additions & 0 deletions snprc_ehr/resources/queries/study/availableChargeIds.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,62 @@
PARAMETERS (
ANIMAL_ID VARCHAR,
EVENT_DATE TIMESTAMP
)

-- Research Charge IDs
SELECT
CAST(p.project AS VARCHAR(40)) AS admitProjectId,
p.project AS projectId,
sp.projectType AS projectType,
0 AS admitId,
RameshRapa marked this conversation as resolved.
Show resolved Hide resolved
sp.description AS projectText,
GREATEST (p.startDate, aaa.date, sp.startDate) AS startDate,
LEAST (p.endDate, TIMESTAMPADD('SQL_TSI_DAY', 1, aaa.endDate), TIMESTAMPADD('SQL_TSI_DAY', 1, sp.endDate), NOW()) AS endDate,
RameshRapa marked this conversation as resolved.
Show resolved Hide resolved
sp.projectId AS projectId,
sp.revisionNum AS revisionNum
FROM ehr.project AS p
INNER JOIN snd.projects AS sp ON p.project = sp.referenceId
INNER JOIN study.assignment aaa ON p.protocol = aaa.protocol AND aaa.assignmentStatus IN ( 'A', 'S')
WHERE aaa.id = ANIMAL_ID
AND GREATEST (p.startDate, aaa.date, sp.startDate) <= EVENT_DATE
AND LEAST (p.endDate, TIMESTAMPADD('SQL_TSI_DAY', 1, aaa.endDate), TIMESTAMPADD('SQL_TSI_DAY', 1, sp.endDate), NOW()) >= EVENT_DATE
-- Maintenance/Behavior Charge IDs
UNION
SELECT DISTINCT
CAST(p.project AS varchar(40)) AS admitProjectId,
p.project AS projectId,
sp.projectType AS projectType,
0 AS admitId,
RameshRapa marked this conversation as resolved.
Show resolved Hide resolved
sp.description AS projectText,
GREATEST (p.startDate, sp.startDate) AS startDate,
LEAST (p.endDate, TIMESTAMPADD('SQL_TSI_DAY', 1, sp.endDate), NOW()) AS endDate,
sp.projectId AS projectId,
sp.revisionNum AS revisionNum
FROM snprc_ehr.validChargeBySpecies AS vcbs
INNER JOIN ehr.project AS p ON p.project = vcbs.project
INNER JOIN study.demographics AS d ON d.id = ANIMAL_ID
INNER JOIN snd.projects AS sp ON vcbs.project = sp.referenceId AND sp.projectType in ('M', 'B') AND CAST(EVENT_DATE AS DATE) BETWEEN sp.startDate AND COALESCE(sp.endDate, NOW())
WHERE d.id = ANIMAL_ID AND vcbs.species = d.species.arc_species_code
AND GREATEST (p.startDate, sp.startDate) <= EVENT_DATE
AND LEAST (p.endDate, TIMESTAMPADD('SQL_TSI_DAY', 1, sp.endDate), NOW()) >= EVENT_DATE
-- Clinical Charge IDs
UNION
SELECT DISTINCT
CAST(c.caseid AS varchar(40)) AS admitProjectId,
p.project AS projectId,
sp.projectType AS projectType,
c.caseid AS admitId,
c.problem + '/' + c.admitcomplaint AS projectText,
GREATEST (c.date, sp.startDate) AS startDate,
LEAST (c.enddate, TIMESTAMPADD('SQL_TSI_DAY', 1, sp.endDate), NOW()) AS endDate,
sp.projectId AS projectId,
sp.revisionNum AS revisionNum
FROM study.cases AS c
INNER JOIN study.demographics AS d ON c.id = ANIMAL_ID
INNER JOIN snprc_ehr.validChargeBySpecies AS vcbs ON c.id = ANIMAL_ID AND vcbs.species = d.species.arc_species_code
INNER JOIN snd.projects AS sp ON vcbs.project = sp.referenceId AND sp.projectType = 'C' AND EVENT_DATE BETWEEN sp.startDate AND COALESCE(sp.endDate, NOW())
INNER JOIN ehr.project AS p ON p.project = vcbs.project AND EVENT_DATE BETWEEN p.startDate AND COALESCE(p.endDate, NOW())
WHERE d.id = ANIMAL_ID
AND vcbs.species = d.species.arc_species_code
AND GREATEST (c.date, sp.startDate) <= EVENT_DATE
AND LEAST (c.endDate, TIMESTAMPADD('SQL_TSI_DAY', 1, sp.endDate), NOW()) >= EVENT_DATE