diff --git a/onprc_ehr/resources/etls/UpdateEhrProtocols.xml b/onprc_ehr/resources/etls/UpdateEhrProtocols.xml
new file mode 100644
index 000000000..9ddf6dec9
--- /dev/null
+++ b/onprc_ehr/resources/etls/UpdateEhrProtocols.xml
@@ -0,0 +1,35 @@
+
+
+
+
+ Update Protocols in EHR
+
+ Runs stored procedures to update the protocol table in schema ehr.
+
+
+
+
+ Determines and populates BaseProtocol and RevisionNumber data for the protocol table in schema onprc_ehr.
+
+
+
+
+
+ Adds enddate data to the protocol table in ehr.
+
+
+
+
+
+
+
+
+
+
+
+
+
diff --git a/onprc_ehr/resources/schemas/dbscripts/sqlserver/onprc_ehr-24.001-24.002.sql b/onprc_ehr/resources/schemas/dbscripts/sqlserver/onprc_ehr-24.001-24.002.sql
new file mode 100644
index 000000000..79c8ec8b6
--- /dev/null
+++ b/onprc_ehr/resources/schemas/dbscripts/sqlserver/onprc_ehr-24.001-24.002.sql
@@ -0,0 +1,7 @@
+--added to allow insert of calculated fields from eIACUC
+
+--2024-12-13 In development need to use a drop if exists statement for these to run
+
+ALTER TABLE onprc_ehr.eIACUC_PRIME_VIEW_PROTOCOLS ADD [BaseProtocol] varchar(100) Null;
+ALTER TABLE onprc_ehr.eIACUC_PRIME_VIEW_PROTOCOLS ADD [RevisionNumber] varchar(100) Null;
+ALTER TABLE onprc_ehr.eIACUC_PRIME_VIEW_PROTOCOLS ADD [NewestRecord] INT Null;
\ No newline at end of file
diff --git a/onprc_ehr/resources/schemas/dbscripts/sqlserver/onprc_ehr-24.002-24.003.sql b/onprc_ehr/resources/schemas/dbscripts/sqlserver/onprc_ehr-24.002-24.003.sql
new file mode 100644
index 000000000..0b8089f6f
--- /dev/null
+++ b/onprc_ehr/resources/schemas/dbscripts/sqlserver/onprc_ehr-24.002-24.003.sql
@@ -0,0 +1,34 @@
+CREATE PROCEDURE onprc_ehr.BaseProtocol
+AS
+BEGIN
+ -- Create a Common Table Expression (CTE) named BaseProtocol
+ WITH BaseProtocol AS
+ (
+ SELECT
+ RowID,
+ Protocol_id,
+ -- Determine the BaseProtocol based on the length of the Protocol_id
+ CASE
+ WHEN LEN(Protocol_id) > 10 THEN SUBSTRING(Protocol_id, 6, 15)
+ ELSE Protocol_id
+ END AS BaseProtocol,
+ -- Determine the RevisionNumber based on the length of the Protocol_id
+ CASE
+ WHEN LEN(Protocol_id) > 10 THEN SUBSTRING(Protocol_id,1, 5)
+ ELSE 'Original'
+ END AS RevisionNumber,
+ approval_date,
+ Three_Year_Expiration,
+ last_modified,
+ Protocol_State
+ FROM onprc_ehr.eIACUC_PRIME_VIEW_PROTOCOLS
+ )
+
+ -- Update the onprc_ehr.eIACUC_PRIME_VIEW_PROTOCOLS table with BaseProtocol and RevisionNumber from the CTE
+ UPDATE onprc_ehr.eIACUC_PRIME_VIEW_PROTOCOLS
+ SET BaseProtocol = BaseProtocol.BaseProtocol,
+ RevisionNumber = BaseProtocol.RevisionNumber
+ FROM BaseProtocol
+ WHERE onprc_ehr.eIACUC_PRIME_VIEW_PROTOCOLS.RowID = BaseProtocol.RowID;
+END
+GO
\ No newline at end of file
diff --git a/onprc_ehr/resources/schemas/dbscripts/sqlserver/onprc_ehr-24.004-24.005.sql b/onprc_ehr/resources/schemas/dbscripts/sqlserver/onprc_ehr-24.004-24.005.sql
new file mode 100644
index 000000000..d6bc68d98
--- /dev/null
+++ b/onprc_ehr/resources/schemas/dbscripts/sqlserver/onprc_ehr-24.004-24.005.sql
@@ -0,0 +1,48 @@
+GO
+/****** Object: StoredProcedure [onprc_ehr].[ExpiredProtocolUpdate] Script Date: 12/20/2024 9:09:09 AM ******/
+SET ANSI_NULLS ON
+GO
+SET QUOTED_IDENTIFIER ON
+GO
+CREATE PROCEDURE [onprc_ehr].[ExpiredProtocolUpdate]
+ AS
+BEGIN
+
+WITH ApprovedProtocols AS (
+ SELECT
+ BaseProtocol,
+ MAX(Approval_Date) AS maxApprovalDate
+ FROM
+ onprc_ehr.eIACUC_PRIME_VIEW_PROTOCOLS
+ WHERE
+ Protocol_State IN ('approved','expired', 'terminated')
+ GROUP BY
+ BaseProtocol
+),
+
+
+ DistinctProtocols AS (
+ SELECT DISTINCT
+ p.rowID,
+ p.BaseProtocol,
+ p.RevisionNumber,
+ p.Protocol_State,
+ p.Approval_Date,
+ p.Last_Modified,
+ p.Three_Year_Expiration
+ FROM
+ onprc_ehr.eIACUC_PRIME_VIEW_PROTOCOLS p
+ INNER JOIN ApprovedProtocols ap ON p.BaseProtocol = ap.BaseProtocol
+ AND p.Approval_Date = ap.maxApprovalDate),
+ ExpiredProtocol AS (
+ Select
+ d.*,
+ p.protocol,
+ p.enddate
+ from DistinctProtocols d inner join ehr.protocol p on d.BaseProtocol = p.external_ID
+ where d.Protocol_State != 'Approved' and p.enddate is Null)
+
+Update p
+ Set p.enddate = getDate()
+ from ehr.protocol p inner join expiredProtocol e on p.external_id = e.BaseProtocol
+END
diff --git a/onprc_ehr/resources/schemas/onprc_ehr.xml b/onprc_ehr/resources/schemas/onprc_ehr.xml
index 12b59e438..5f5b3a307 100644
--- a/onprc_ehr/resources/schemas/onprc_ehr.xml
+++ b/onprc_ehr/resources/schemas/onprc_ehr.xml
@@ -735,6 +735,9 @@
+
+
+
diff --git a/onprc_ehr/src/org/labkey/onprc_ehr/ONPRC_EHRModule.java b/onprc_ehr/src/org/labkey/onprc_ehr/ONPRC_EHRModule.java
index df0f81a3f..5ec60e1d9 100644
--- a/onprc_ehr/src/org/labkey/onprc_ehr/ONPRC_EHRModule.java
+++ b/onprc_ehr/src/org/labkey/onprc_ehr/ONPRC_EHRModule.java
@@ -126,7 +126,7 @@ public String getName()
@Override
public @Nullable Double getSchemaVersion()
{
- return 23.016;
+ return 24.005;
}
@Override