-
Notifications
You must be signed in to change notification settings - Fork 4
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
Merge pull request #54 from EdwardKaravakis/main
Port Oracle changes to Postgres
- Loading branch information
Showing
4 changed files
with
115 additions
and
2 deletions.
There are no files selected for viewing
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,61 @@ | ||
-- patch to be used to upgrade from version 0.0.15 | ||
|
||
-- MODIFICATIONTIME TRIGGER | ||
-- New column JEDI_TASKS.REALMODIFICATIONTIME | ||
ALTER TABLE jedi_tasks ADD realmodificationtime timestamp; | ||
COMMENT ON COLUMN jedi_tasks.realmodificationtime IS E'Set ALWAYS to last modification time, without any tricks like old timestamps'; | ||
|
||
CREATE INDEX jedi_tasks_realmodtime_idx ON jedi_tasks (realmodificationtime); | ||
|
||
-- Trigger to set JEDI_TASKS.REALMODIFICATIONTIME to current UTC timestamp | ||
DROP TRIGGER IF EXISTS update_realmodificationtime ON jedi_tasks CASCADE; | ||
-- Trigger to set JEDI_TASKS.REALMODIFICATIONTIME to current UTC timestamp | ||
CREATE OR REPLACE FUNCTION update_realmodificationtime_trg() RETURNS trigger AS $BODY$ | ||
BEGIN | ||
IF (TG_OP = 'INSERT') THEN | ||
NEW.realmodificationtime := CURRENT_TIMESTAMP AT TIME ZONE 'UTC'; | ||
ELSIF (TG_OP = 'UPDATE') THEN | ||
IF NEW.modificationtime <> OLD.modificationtime THEN | ||
NEW.realmodificationtime := CURRENT_TIMESTAMP AT TIME ZONE 'UTC'; | ||
END IF; | ||
END IF; | ||
RETURN NEW; | ||
END | ||
$BODY$ | ||
LANGUAGE 'plpgsql'; | ||
|
||
ALTER FUNCTION update_realmodificationtime_trg() OWNER TO panda; | ||
|
||
CREATE TRIGGER update_realmodificationtime | ||
BEFORE INSERT OR UPDATE ON jedi_tasks FOR EACH ROW | ||
EXECUTE PROCEDURE update_realmodificationtime_trg(); | ||
/ | ||
|
||
-- SQL_QUEUE TABLE | ||
|
||
CREATE TABLE sql_queue | ||
( | ||
topic varchar(50), | ||
pandaid bigint, | ||
execution_order integer, | ||
jeditaskid bigint, | ||
creationtime timestamp, | ||
data VARCHAR(4000) | ||
); | ||
|
||
CREATE INDEX sql_queue_topic_task_idx ON sql_queue (topic, jeditaskid); | ||
CREATE INDEX sql_queue_topic_creationtime_idx ON sql_queue (topic, creationtime); | ||
COMMENT ON TABLE sql_queue IS E'Queue to send messages between agents'; | ||
COMMENT ON COLUMN sql_queue.topic IS E'Topic of the message'; | ||
COMMENT ON COLUMN sql_queue.pandaid IS E'Job ID'; | ||
COMMENT ON COLUMN sql_queue.execution_order IS E'In case multiple SQLs need to be executed together'; | ||
COMMENT ON COLUMN sql_queue.jeditaskid IS E'JEDI Task ID in case the messages want to be batched'; | ||
COMMENT ON COLUMN sql_queue.creationtime IS E'Timestamp when the message was created'; | ||
COMMENT ON COLUMN sql_queue.data IS E'CLOB in JSON format containing the SQL query and variables'; | ||
ALTER TABLE sql_queue ADD PRIMARY KEY (topic, pandaid, execution_order); | ||
|
||
|
||
-- Update versions | ||
UPDATE pandadb_version SET major=0, minor=0, patch=16 where component='JEDI'; | ||
UPDATE pandadb_version SET major=0, minor=0, patch=16 where component='SERVER'; | ||
COMMIT; |
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
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,30 @@ | ||
SET client_encoding TO 'UTF8'; | ||
|
||
SET search_path = doma_panda,public; | ||
|
||
\set ON_ERROR_STOP ON | ||
|
||
SET check_function_bodies = false; | ||
|
||
DROP TRIGGER IF EXISTS update_realmodificationtime ON jedi_tasks CASCADE; | ||
-- Trigger to set JEDI_TASKS.REALMODIFICATIONTIME to current UTC timestamp | ||
CREATE OR REPLACE FUNCTION update_realmodificationtime_trg() RETURNS trigger AS $BODY$ | ||
BEGIN | ||
IF (TG_OP = 'INSERT') THEN | ||
NEW.realmodificationtime := CURRENT_TIMESTAMP AT TIME ZONE 'UTC'; | ||
ELSIF (TG_OP = 'UPDATE') THEN | ||
IF NEW.modificationtime <> OLD.modificationtime THEN | ||
NEW.realmodificationtime := CURRENT_TIMESTAMP AT TIME ZONE 'UTC'; | ||
END IF; | ||
END IF; | ||
RETURN NEW; | ||
END | ||
$BODY$ | ||
LANGUAGE 'plpgsql'; | ||
|
||
ALTER FUNCTION update_realmodificationtime_trg() OWNER TO panda; | ||
|
||
CREATE TRIGGER update_realmodificationtime | ||
BEFORE INSERT OR UPDATE ON jedi_tasks FOR EACH ROW | ||
EXECUTE PROCEDURE update_realmodificationtime_trg(); | ||
/ |
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 |
---|---|---|
@@ -1 +1 @@ | ||
0.0.15 | ||
0.0.16 |