Skip to content

Commit dff87fe

Browse files
committed
Merge branch 'main' into DBA-834
2 parents d5a3335 + 4ccae68 commit dff87fe

File tree

7 files changed

+160
-73
lines changed

7 files changed

+160
-73
lines changed

.github/workflows/oracle-db-password-rotation-schedule.json

+4
Original file line numberDiff line numberDiff line change
@@ -7,6 +7,10 @@
77
"TargetEnvironment":"delius-mis-dev",
88
"CronSchedule":"00 12 * * TUE"
99
},
10+
{
11+
"TargetEnvironment":"delius-mis-stage",
12+
"CronSchedule":"00 14 * * THU"
13+
},
1014
{
1115
"TargetEnvironment":"delius-core-test",
1216
"CronSchedule":"00 14 * * TUE"

.github/workflows/oracle-db-password-rotation-schedule.yml

+1
Original file line numberDiff line numberDiff line change
@@ -4,6 +4,7 @@ on:
44
- cron: '00 12 * * TUE'
55
- cron: '00 14 * * TUE'
66
- cron: '00 10 * * THU'
7+
- cron: '00 14 * * THU'
78

89
jobs:
910
prepare-run-matrix:

helm/migrate-db/Chart.yaml

+5
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,5 @@
1+
apiVersion: v2
2+
appVersion: 0.1
3+
version: 0.0.1
4+
description: A Helm chart for deploying a job to migrate DB data
5+
name: migrate-db
+25
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,25 @@
1+
---
2+
apiVersion: v1
3+
kind: ConfigMap
4+
metadata:
5+
name: migrate-db-script
6+
data:
7+
entrypoint.sh: |-
8+
#!/bin/bash
9+
set -e
10+
echo "${SRC_DB_HOST}:5432:${SRC_DB_NAME}:${SRC_DB_USER}:${SRC_DB_PASS}" > ~/.pgpass
11+
echo "${DST_DB_HOST}:5432:${DST_DB_NAME}:${DST_DB_USER}:${DST_DB_PASS}" >> ~/.pgpass
12+
chmod 0600 ~/.pgpass
13+
chown job:job ~/.pgpass
14+
set -x
15+
16+
# Dump the source database
17+
pg_dump --jobs=4 --host="$SRC_DB_HOST" --username="$SRC_DB_USER" --dbname="$SRC_DB_NAME" --no-owner --no-privileges --verbose --format=directory --file=/home/job/db-dump
18+
19+
psql --host="$DST_DB_HOST" --username="$DST_DB_USER" --dbname="$DST_DB_NAME" -c "drop schema if exists public cascade;"
20+
21+
psql --host="$DST_DB_HOST" --username="$DST_DB_USER" --dbname="$DST_DB_NAME" -c "create schema public;"
22+
23+
# Restore the source database dump to the destination database
24+
pg_restore --jobs=4 --host="$DST_DB_HOST" --username="$DST_DB_USER" --dbname="$DST_DB_NAME" --no-owner --no-privileges --verbose /home/job/db-dump
25+
rm -rv /home/job/db-dump ~/.pgpass

helm/migrate-db/templates/job.yaml

+84
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,84 @@
1+
---
2+
apiVersion: batch/v1
3+
kind: Job
4+
metadata:
5+
name: migrate-db
6+
spec:
7+
template:
8+
spec:
9+
containers:
10+
- name: migrate-db
11+
image: ghcr.io/ministryofjustice/hmpps-delius-alfresco-db-utils:latest # move this image to this repo
12+
imagePullPolicy: IfNotPresent
13+
resources:
14+
limits:
15+
cpu: 4
16+
memory: 2Gi
17+
command:
18+
- /bin/entrypoint.sh
19+
env:
20+
- name: SRC_DB_NAME
21+
valueFrom:
22+
secretKeyRef:
23+
name: legacy-rds-instance-{{ .Values.component }}
24+
key: DATABASE_NAME
25+
- name: SRC_DB_USER
26+
valueFrom:
27+
secretKeyRef:
28+
name: legacy-rds-instance-{{ .Values.component }}
29+
key: DATABASE_USERNAME
30+
- name: SRC_DB_PASS
31+
valueFrom:
32+
secretKeyRef:
33+
name: legacy-rds-instance-{{ .Values.component }}
34+
key: DATABASE_PASSWORD
35+
- name: SRC_DB_HOST
36+
valueFrom:
37+
secretKeyRef:
38+
name: legacy-rds-instance-{{ .Values.component }}
39+
key: RDS_INSTANCE_ADDRESS
40+
- name: DST_DB_NAME
41+
valueFrom:
42+
secretKeyRef:
43+
name: rds-instance-output-{{ .Values.component }}
44+
key: DATABASE_NAME
45+
- name: DST_DB_USER
46+
valueFrom:
47+
secretKeyRef:
48+
name: rds-instance-output-{{ .Values.component }}
49+
key: DATABASE_USERNAME
50+
- name: DST_DB_PASS
51+
valueFrom:
52+
secretKeyRef:
53+
name: rds-instance-output-{{ .Values.component }}
54+
key: DATABASE_PASSWORD
55+
- name: DST_DB_HOST
56+
valueFrom:
57+
secretKeyRef:
58+
name: rds-instance-output-{{ .Values.component }}
59+
key: RDS_INSTANCE_ADDRESS
60+
volumeMounts:
61+
- name: migrate-db-script
62+
mountPath: /bin/entrypoint.sh
63+
readOnly: true
64+
subPath: entrypoint.sh
65+
securityContext:
66+
allowPrivilegeEscalation: false
67+
privileged: false
68+
readOnlyRootFilesystem: false
69+
runAsNonRoot: true
70+
runAsUser: 999
71+
capabilities:
72+
drop:
73+
- ALL
74+
seccompProfile:
75+
type: RuntimeDefault
76+
serviceAccount: hmpps-migration-{{ .Values.environment }}
77+
serviceAccountName: hmpps-migration-{{ .Values.environment }}
78+
restartPolicy: Never
79+
volumes:
80+
- name: migrate-db-script
81+
configMap:
82+
name: migrate-db-script
83+
defaultMode: 0755
84+
backoffLimit: 0

playbooks/delius_audit_replication_schema/delius_audit_replication_schema/files/disable_user_update.sh

+41-4
Original file line numberDiff line numberDiff line change
@@ -28,10 +28,22 @@ END LOOP;
2828
END;
2929
/
3030
31+
-- Incoming USER_ INSERTs may contain STAFF_IDs which may or may not exist in stage
32+
-- or pre-prod; we allow the DELIUS_USER_SUPPORT audit control check if they exist
33+
-- so that we can set any invalid STAFF_IDs to NULL and allow the rest of the USER_
34+
-- record to be created.
35+
GRANT SELECT ON delius_app_schema.staff TO delius_user_support;
36+
37+
-- We do not wish to generate CDC records for LAST_ACCESSED_DATETIME as user access
38+
-- times in the repository database have no baring on those on the client. We
39+
-- use the Unilink-supplied PKG_TRIGGERSUPPORT package to temporarily disable
40+
-- CDC capture on USER_ if no personal details have been changed.
41+
GRANT EXECUTE ON delius_app_schema.pkg_triggersupport TO delius_user_support;
42+
3143
-- Additionally we add a trigger to enforce the same restrictions for the Application Schema itself.
3244
-- This trigger is also used to workaround a difference between NLS Date formats used in DMS
3345
-- and those used by the Delius application.
34-
CREATE OR REPLACE TRIGGER delius_user_support.audit_control_on_user_
46+
create or replace TRIGGER delius_user_support.audit_control_on_user_
3547
FOR delete OR update OR insert ON delius_app_schema.user_
3648
COMPOUND TRIGGER
3749
@@ -51,6 +63,7 @@ COMPOUND TRIGGER
5163
END BEFORE STATEMENT;
5264
5365
BEFORE EACH ROW IS
66+
l_staff_id_exists INTEGER;
5467
BEGIN
5568
IF USER = 'DELIUS_AUDIT_DMS_POOL'
5669
THEN
@@ -69,10 +82,10 @@ COMPOUND TRIGGER
6982
*/
7083
EXECUTE IMMEDIATE 'ALTER SESSION SET nls_date_format = ''YYYY-MM-DD HH24:MI:SS''';
7184
EXECUTE IMMEDIATE 'ALTER SESSION SET nls_timestamp_format = ''YYYY-MM-DD HH24:MI:SS.FF9''';
72-
73-
85+
86+
7487
/*
75-
There are multiple reasons why the Delius application may update the
88+
There are multiple reasons why the Delius application may update the
7689
LAST_UPDATED_USER_ID and LAST_UPDATED_DATETIME columns, but not all of these involve
7790
attributes which are replicated to the client database. This can cause confusion
7891
if these attributes are updated but nothing appears to have changed.
@@ -94,13 +107,35 @@ COMPOUND TRIGGER
94107
-- did not impact data that was replicated.
95108
:new.last_updated_user_id := :old.last_updated_user_id;
96109
:new.last_updated_datetime := :old.last_updated_datetime;
110+
-- Also do not update the row version as no actual change has been made
111+
:new.row_version := :old.row_version;
112+
-- Disable CDC for the user record if no actual personal data change
113+
-- (This is to prevent last accessed datetime records from production
114+
-- triggering CDC even when we suppress the change in the trigger).
115+
delius_app_schema.pkg_triggersupport.procSetCDCFlag(FALSE);
97116
END IF;
98117
-- Staff IDs in stage and pre-prod are independent of those in production
99118
-- since these are not relevant to audit, and it may be necessary for
100119
-- some users to have staff records in stage and pre-prod without having
101120
-- corresponding records in production. Therefore we prevent any overwriting
102121
-- of the staff ID
103122
:new.staff_id := :old.staff_id;
123+
-- We ignore changes to LAST_ACCESSED_DATETIME as this is the time the user was
124+
-- accessed in the repository which is not relevant to the local database
125+
:new.last_accessed_datetime := :old.last_accessed_datetime;
126+
ELSIF INSERTING THEN
127+
-- Also, not all Staff IDs from production will exist in stage & pre-prod
128+
-- so it we are attempting to insert a new user with a non-existent staff_id
129+
-- we simply set it to NULL
130+
SELECT CASE WHEN EXISTS (
131+
SELECT 1
132+
FROM delius_app_schema.staff
133+
WHERE staff_id = :new.staff_id
134+
) THEN 1 ELSE 0 END
135+
INTO l_staff_id_exists FROM DUAL;
136+
IF l_staff_id_exists = 0 THEN
137+
:new.staff_id := NULL;
138+
END IF;
104139
END IF;
105140
END IF;
106141
@@ -132,6 +167,8 @@ COMPOUND TRIGGER
132167
BEGIN
133168
IF USER = 'DELIUS_AUDIT_DMS_POOL'
134169
THEN
170+
-- Reset CDC Flag to default value
171+
delius_app_schema.pkg_triggersupport.procSetCDCFlag(NULL);
135172
EXECUTE IMMEDIATE 'ALTER SESSION SET nls_date_format = ''YYYY-MM-DD HH24:MI:SS''';
136173
EXECUTE IMMEDIATE 'ALTER SESSION SET nls_timestamp_format = ''YYYY-MM-DD HH24:MI:SS.FF9''';
137174
END IF;

playbooks/oracle_release_update/oracle_release_update/tasks/update_oem_targets.yml

-69
This file was deleted.

0 commit comments

Comments
 (0)