Skip to content
Open
Show file tree
Hide file tree
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
44 changes: 44 additions & 0 deletions onprc_ehr/resources/queries/ehr_lookups/availableCagesByDate.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,44 @@
-- Created by Kollil, Oct 2025
-- This query is a variation of the same one in the folder, but, with a date as parameter

PARAMETERS(SnapshotDate TIMESTAMP)

SELECT
CASE WHEN c.cage IS NULL THEN c.room ELSE (c.room || '-' || c.cage) END AS location,
c.room,
c.cage,
c.cagePosition.row,
c.cagePosition.columnIdx,
c.cage_type,
lc.cage AS lowerCage,
lc.cage_type AS lower_cage_type,
lc.divider AS divider,
CASE
WHEN c.cage_type = 'No Cage' THEN FALSE
WHEN COALESCE(lc.divider.countAsSeparate, TRUE) = FALSE THEN FALSE
ELSE TRUE
END AS isAvailable,
CASE WHEN c.status IS NOT NULL AND c.status = 'Unavailable' THEN 1 ELSE 0 END AS isMarkedUnavailable,
-- Example: occupancy "as of" SnapshotDate from study.housing
CASE WHEN h.Id IS NOT NULL THEN 1 ELSE 0 END AS isOccupiedAsOf,
-- Echo the effective date we used (handy for debugging)
COALESCE(SnapshotDate, NOW()) AS AsOfDate

FROM ehr_lookups.cage AS c

-- left-hand neighbor (structural)
LEFT JOIN ehr_lookups.cage AS lc
ON c.room = lc.room
AND c.cagePosition.row = lc.cagePosition.row
AND c.cagePosition.columnIdx - 1 = lc.cagePosition.columnIdx
AND lc.cage_type <> 'No Cage'

-- time-varying occupancy example (adjust table/columns to your schema):
LEFT JOIN study.housing AS h
ON h.room = c.room
AND ( (h.cage IS NULL AND c.cage IS NULL) OR h.cage = c.cage )
-- "as of" predicate using the parameter
AND h.date <= COALESCE(SnapshotDate, NOW())
AND (h.enddate IS NULL OR h.enddate > COALESCE(SnapshotDate, NOW()))

WHERE c.room.housingType.value = 'Cage Location'
Original file line number Diff line number Diff line change
@@ -0,0 +1,23 @@
/*
* Copyright (c) 2013-2018 LabKey Corporation
*
* Licensed under the Apache License, Version 2.0 (the "License");
* you may not use this file except in compliance with the License.
* You may obtain a copy of the License at
*
* http://www.apache.org/licenses/LICENSE-2.0
*
* Unless required by applicable law or agreed to in writing, software
* distributed under the License is distributed on an "AS IS" BASIS,
* WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied.
* See the License for the specific language governing permissions and
* limitations under the License.
*/
SELECT
c.room,
count(*) as availableCages,
sum(c.isMarkedUnavailable) as markedUnavailable

FROM ehr_lookups.availableCagesByDate c
WHERE c.isAvailable = true
GROUP BY c.room
Original file line number Diff line number Diff line change
@@ -0,0 +1,87 @@

<query xmlns="http://labkey.org/data/xml/query">
<metadata>
<tables xmlns="http://labkey.org/data/xml">
<table tableName="roomUtilizationByDate" tableDbType="NOT_IN_DB">
<tableTitle>Room Utilization By Date</tableTitle>
<javaCustomizer class="org.labkey.ehr.table.DefaultEHRCustomizer" />
<columns>
<column columnName="room">
<isKeyField>true</isKeyField>
<fk>
<fkDbSchema>ehr_lookups</fkDbSchema>
<fkTable>rooms</fkTable>
<fkColumnName>room</fkColumnName>
</fk>
</column>
<column columnName="SnapshotDate">
<columnTitle>Snapshot Date</columnTitle>
</column>
<column columnName="TotalCages">
<columnTitle>Total Cage Spaces</columnTitle>
<displayWidth>50</displayWidth>
<url>/query/executeQuery.view?
schemaName=ehr_lookups&amp;
query.queryName=cage&amp;
query.room~eq=${room}&amp;
query.sort=cage&amp;
</url>
</column>
<column columnName="AvailableCages">
<columnTitle>Total Cages Present</columnTitle>
<displayWidth>50</displayWidth>
<url>/query/executeQuery.view?
schemaName=ehr_lookups&amp;
query.queryName=availableCages&amp;
query.room~eq=${room}&amp;
query.isAvailable~eq=true&amp;
query.sort=cage&amp;
</url>
</column>
<column columnName="MarkedUnavailable">
<columnTitle>Marked Unavailable</columnTitle>
</column>
<column columnName="CagesUsed">
<columnTitle>Cages Used</columnTitle>
<displayWidth>40</displayWidth>
<url>/query/executeQuery.view?
schemaName=ehr_lookups&amp;
query.queryName=cage&amp;
query.room~eq=${room}&amp;
query.availability/isAvailable~eq=true&amp;
query.totalAnimals/totalAnimals~gt=0&amp;
query.sort=cage&amp;
</url>
</column>
<column columnName="CagesEmpty">
<columnTitle>Cages Empty</columnTitle>
<displayWidth>40</displayWidth>
<url>/query/executeQuery.view?
schemaName=ehr_lookups&amp;
query.queryName=cage&amp;
query.room~eq=${room}&amp;
query.availability/isAvailable~eq=true&amp;
query.totalAnimals/totalAnimals~isblank&amp;
query.sort=cage&amp;
</url>
</column>
<column columnName="pctUsed">
<displayWidth>40</displayWidth>
<columnTitle>% Used</columnTitle>
</column>
<column columnName="TotalAnimals">
<columnTitle>Total Animals</columnTitle>
<displayWidth>50</displayWidth>
<url>/query/executeQuery.view?
schemaName=study&amp;
query.queryName=Demographics&amp;
query.viewName=By Location&amp;
query.Id/curLocation/room~eq=${room}&amp;
query.sort=Id&amp;
</url>
</column>
</columns>
</table>
</tables>
</metadata>
</query>
48 changes: 48 additions & 0 deletions onprc_ehr/resources/queries/ehr_lookups/roomUtilizationByDate.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,48 @@
/* Added by: Kollil, 9/29/2025, Refer tkt # 13276
Created a query that mimics the Room Utilization Report with the With PI Projects view, but with the additional feature
that it can be run for arbitrary prior dates.
Lisa requested this new reports and is very useful
*/
PARAMETERS (SnapshotDate TIMESTAMP)

SELECT
r.room,
-- p.SnapDate AS SnapshotDate, -- echoes the effective date
COUNT(DISTINCT c.cage) AS TotalCages,
MAX(cbr.availableCages) AS AvailableCages,
MAX(cbr.markedUnavailable) AS MarkedUnavailable,
COUNT(DISTINCT h.cage) AS CagesUsed,
MAX(cbr.availableCages) - COUNT(DISTINCT h.cage) - MAX(cbr.markedUnavailable) AS CagesEmpty,
ROUND(
(
(CAST(COUNT(DISTINCT h.cage) AS DOUBLE) + MAX(cbr.markedUnavailable))
/ NULLIF(CAST(MAX(cbr.availableCages) AS DOUBLE), 0)
) * 100.0, 1
) AS pctUsed,
COUNT(DISTINCT h.id) AS TotalAnimals
FROM ehr_lookups.rooms r
-- bind the parameter once; default to today when blank
LEFT JOIN (
SELECT COALESCE(SnapshotDate, now()) AS SnapDate
) p ON 1=1

LEFT JOIN (
SELECT c1.room, c1.cage
FROM ehr_lookups.cage c1
WHERE c1.cage IS NOT NULL
UNION ALL
SELECT r2.room, NULL AS cage
FROM ehr_lookups.rooms r2
) c ON r.room = c.room

LEFT JOIN study.housing h
ON r.room = h.room
AND (c.cage = h.cage OR (c.cage IS NULL AND h.cage IS NULL))
AND h.date <= p.SnapDate
AND (h.enddate IS NULL OR h.enddate > p.SnapDate)

LEFT JOIN ehr_lookups.availableCagesByRoomByDate cbr
ON cbr.room = r.room
WHERE r.datedisabled IS NULL
GROUP BY r.room, p.SnapDate
ORDER BY r.room;
4 changes: 2 additions & 2 deletions onprc_ehr/resources/views/begin.html
Original file line number Diff line number Diff line change
Expand Up @@ -102,13 +102,13 @@
{name: 'Animal Groups', url: '<%=contextPath%>' + ctx['EHRStudyContainer'] + '/query-executeQuery.view?schemaName=ehr&query.queryName=animal_groups&query.viewName=Active Groups'},
{name: 'Colony Overview', url: '<%=contextPath%>' + ctx['EHRStudyContainer'] + '/onprc_ehr-colonyOverview.view'},
{name: 'Room Utilization', url: '<%=contextPath%>' + ctx['EHRStudyContainer'] + '/query-executeQuery.view?schemaName=ehr_lookups&query.queryName=roomUtilization'},
//Added by Kollil on 9/29/25
{name: 'Room Utilization By Date', url: '<%=contextPath%>' + ctx['EHRStudyContainer'] + '/query-executeQuery.view?schemaName=ehr_lookups&query.queryName=roomUtilizationByDate'},
{name: 'More Reports', url: '<%=contextPath%>' + ctx['EHRStudyContainer'] + '/ehr-moreReports.view'}
]
}]
});



var menuCfg = {
width: 330,
renderTo: 'ehrMenu3_'+webpart.wrapperDivId,
Expand Down