-
Notifications
You must be signed in to change notification settings - Fork 11
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
- Loading branch information
Showing
4 changed files
with
138 additions
and
2 deletions.
There are no files selected for viewing
109 changes: 109 additions & 0 deletions
109
infrastructure/DBScripts/PharmanetTransactionLogs_Partition.sql
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,109 @@ | ||
-- Original author is Ciaran Rice | ||
-- Script was executed as `postgres` (administrator) user | ||
-- Includes latest partition SQL (`PharmanetTransactionLog_p2024_Q3`), executed as `postgres` 2024-05-01 | ||
|
||
BEGIN; | ||
|
||
-- Fisrt alter the name of the existing large table & any constraints | ||
ALTER TABLE "PharmanetTransactionLog" RENAME TO PharmanetTransactionLog_2021_2022_07; | ||
ALTER TABLE PharmanetTransactionLog_2021_2022_07 DROP CONSTRAINT "PK_PharmanetTransactionLog"; --RENAME CONSTRAINT "PK_PharmanetTransactionLog" TO "PK_PharmanetTransactionLog_Legacy"; | ||
|
||
-- Alter the names off all table indexes | ||
ALTER INDEX IF EXISTS "IX_PharmanetTransactionLog_PharmacyId" RENAME TO "IX_PharmanetTransactionLog_2021_2022_07_PharmacyId"; | ||
ALTER INDEX IF EXISTS "IX_PharmanetTransactionLog_TransactionId" RENAME TO "IX_PharmanetTransactionLog_2021_2022_07_TransactionId"; | ||
ALTER INDEX IF EXISTS "IX_PharmanetTransactionLog_TxDateTime" RENAME TO "IX_PharmanetTransactionLog_2021_2022_07_TxDateTime"; | ||
ALTER INDEX IF EXISTS "IX_PharmanetTransactionLog_UserId" RENAME TO "IX_PharmanetTransactionLog_2021_2022_07_UserId"; | ||
|
||
-- Create a new table with the original table name, now partitioned by Range of TxDateTime | ||
CREATE TABLE "PharmanetTransactionLog" ( | ||
"Id" int8 NOT NULL GENERATED BY DEFAULT AS IDENTITY , | ||
"CreatedTimeStamp" timestamptz NOT NULL DEFAULT CURRENT_TIMESTAMP, | ||
"TransactionId" int8 NOT NULL, | ||
"TxDateTime" timestamp NOT NULL, | ||
"UserId" text NULL, | ||
"PharmacyId" text NULL, | ||
"TransactionType" text NULL, | ||
"TransactionSubType" text NULL, | ||
"PractitionerId" text NULL, | ||
"CollegePrefix" text NULL, | ||
"TransactionOutcome" text NULL, | ||
"ProviderSoftwareId" text NULL, | ||
"ProviderSoftwareVersion" text NULL, | ||
"LocationIpAddress" text NULL, | ||
"SourceIpAddress" text NULL, | ||
CONSTRAINT "PK_PharmanetTransactionLog" PRIMARY KEY ("Id","TxDateTime") | ||
|
||
) PARTITION BY RANGE ("TxDateTime"); | ||
|
||
-- Create indexes as they were originally | ||
CREATE INDEX IF NOT EXISTS "IX_PharmanetTransactionLog_PharmacyId" ON public."PharmanetTransactionLog" USING btree ("PharmacyId"); | ||
CREATE INDEX IF NOT EXISTS "IX_PharmanetTransactionLog_TransactionId" ON public."PharmanetTransactionLog" USING btree ("TransactionId"); | ||
CREATE INDEX IF NOT EXISTS "IX_PharmanetTransactionLog_TxDateTime" ON public."PharmanetTransactionLog" USING btree ("TxDateTime"); | ||
CREATE INDEX IF NOT EXISTS "IX_PharmanetTransactionLog_UserId" ON public."PharmanetTransactionLog" USING btree ("UserId"); | ||
|
||
GRANT INSERT, SELECT, UPDATE, DELETE, TRUNCATE, REFERENCES, TRIGGER | ||
ON "PharmanetTransactionLog" | ||
TO prime_user; | ||
|
||
DO $$ -- PLPGSQL annonymous code block | ||
|
||
BEGIN | ||
-- Only because we know and trust the data. Accept the constraint is satisfied. | ||
ALTER TABLE PharmanetTransactionLog_2021_2022_07 | ||
ADD CONSTRAINT PharmanetTransactionLog_2021_2022_07_txdate | ||
CHECK ("TxDateTime" >= '2021-01-01' AND "TxDateTime" < '2022-08-01') NOT VALID; | ||
-- Avoids total table scan and allows us to add table to partition with minimal logging | ||
UPDATE pg_constraint | ||
SET convalidated = TRUE | ||
WHERE conname = 'PharmanetTransactionLog_2021_2022_07_txdate'; | ||
-- Attach legacy table to new partition table | ||
|
||
ALTER TABLE "PharmanetTransactionLog" | ||
ATTACH PARTITION PharmanetTransactionLog_2021_2022_07 | ||
FOR VALUES FROM ('2021-01-01') to ('2022-08-01'); | ||
END; | ||
$$ LANGUAGE PLPGSQL; | ||
COMMIT; | ||
|
||
-- Create future partitions | ||
CREATE TABLE PharmanetTransactionLog_p2022_0812 -- fill remainder of 2022 data | ||
PARTITION OF "PharmanetTransactionLog" | ||
FOR VALUES FROM ('2022-08-01') TO ('2023-01-01'); | ||
|
||
CREATE TABLE PharmanetTransactionLog_p2023_Q1 -- Quarterly partitions | ||
PARTITION OF "PharmanetTransactionLog" | ||
FOR VALUES FROM ('2023-01-01') TO ('2023-04-01'); | ||
|
||
CREATE TABLE PharmanetTransactionLog_p2023_Q2 | ||
PARTITION OF "PharmanetTransactionLog" | ||
FOR VALUES FROM ('2023-04-01') TO ('2023-07-01'); | ||
|
||
CREATE TABLE PharmanetTransactionLog_p2023_Q3 | ||
PARTITION OF "PharmanetTransactionLog" | ||
FOR VALUES FROM ('2023-07-01') TO ('2023-10-01'); | ||
|
||
CREATE TABLE PharmanetTransactionLog_p2023_Q4 | ||
PARTITION OF "PharmanetTransactionLog" | ||
FOR VALUES FROM ('2023-10-01') TO ('2024-01-01'); | ||
|
||
CREATE TABLE PharmanetTransactionLog_p2024_Q1 | ||
PARTITION OF "PharmanetTransactionLog" | ||
FOR VALUES FROM ('2024-01-01') TO ('2024-04-01'); | ||
|
||
CREATE TABLE PharmanetTransactionLog_p2024_Q2 | ||
PARTITION OF "PharmanetTransactionLog" | ||
FOR VALUES FROM ('2024-04-01') TO ('2024-07-01'); | ||
|
||
CREATE TABLE PharmanetTransactionLog_p2024_Q3 | ||
PARTITION OF "PharmanetTransactionLog" | ||
FOR VALUES FROM ('2024-07-01') TO ('2024-10-01'); | ||
|
||
CREATE TABLE PharmanetTransactionLog_DEFAULT | ||
PARTITION OF "PharmanetTransactionLog" | ||
DEFAULT; | ||
-- ROLLBACK | ||
|
||
--SELECT VERSION() | ||
|
||
|
||
|
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,27 @@ | ||
# UPGRADE the version of Metabase if you’re running 45 or below | ||
|
||
### 1. Download the latest version of Metabase image from docker hub | ||
|
||
`docker pull metabase/metabase:latest` | ||
|
||
### 2. Login to OpenShift | ||
`oc login <token>` | ||
|
||
### 3. Switch to the desired project | ||
`oc project <namescapce>` | ||
|
||
### 4. Tag the downloaded image | ||
|
||
`docker tag metabase/metabase:latest image-registry.apps.silver.devops.gov.bc.ca/<namespace>/metabase:<image-version>` | ||
|
||
### 5. Login to docker and Push the image to the metabase imagestream in tools namespace | ||
|
||
`docker login -u 'oc whoami' -p <password> image-registry.apps.silver.devops.gov.bc.ca/<namespace>` | ||
|
||
`docker push image-registry.apps.silver.devops.gov.bc.ca/<namespace>/metabase:<image-version>` | ||
|
||
### 6. Point the latest image in metabase imagestream to the newly downloaded image | ||
|
||
`oc tag metabase:v0.47.2 metabase:latest` | ||
|
||
|
File renamed without changes.
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters