Skip to content

Commit bc85fd6

Browse files
Merge pull request #92 from PanDAWMS/eddiedev
[ATLASPANDA-1238] DB version 0.0.23: add system metric related tables…
2 parents bc0acf3 + b620a42 commit bc85fd6

File tree

5 files changed

+174
-28
lines changed

5 files changed

+174
-28
lines changed

schema/postgres/sqls/patches/0.0.22.patch.sql

Lines changed: 2 additions & 2 deletions
Original file line numberDiff line numberDiff line change
@@ -1,6 +1,6 @@
11
-- patch to be used to upgrade from version 0.0.21
22
CREATE TABLE doma_panda.error_classification (
3-
id BIGINT GENERATED ALWAYS AS IDENTITY (START WITH 1000000 INCREMENT BY 1) NOT NULL,
3+
"id" BIGINT GENERATED ALWAYS AS IDENTITY (START WITH 1000000 INCREMENT BY 1) NOT NULL,
44
"error_source" VARCHAR(30) NOT NULL,
55
"error_code" bigint NOT NULL,
66
"error_diag" VARCHAR(256) NOT NULL,
@@ -19,7 +19,7 @@ COMMENT ON COLUMN doma_panda.error_classification.error_class IS E'Error class:
1919
COMMENT ON COLUMN doma_panda.error_classification.active IS E'Y or N. Depending on whether the entry is confirmed';
2020
COMMENT ON COLUMN doma_panda.error_classification.reg_date IS E'Registration date, defaults to current timestamp';
2121
ALTER TABLE doma_panda.error_classification OWNER TO panda;
22-
ALTER TABLE doma_panda.error_classification ADD PRIMARY KEY (id);
22+
ALTER TABLE doma_panda.error_classification ADD PRIMARY KEY ("id");
2323

2424
-- Update versions
2525
UPDATE doma_panda.pandadb_version SET major=0, minor=0, patch=22 where component='JEDI';
Lines changed: 85 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,85 @@
1+
-- patch to be used to upgrade from version 0.0.22
2+
CREATE TABLE doma_panda.job_metrics (
3+
"pandaid" BIGINT NOT NULL,
4+
"jeditaskid" BIGINT,
5+
"creationtime" TIMESTAMP,
6+
"modificationtime" TIMESTAMP,
7+
"data" TEXT
8+
) PARTITION BY RANGE (modificationtime);
9+
COMMENT ON TABLE doma_panda.job_metrics IS E'System metrics per job';
10+
COMMENT ON COLUMN doma_panda.job_metrics.pandaid IS E'PandaID for the job';
11+
COMMENT ON COLUMN doma_panda.job_metrics.jeditaskid IS E'JEDI task ID for the job';
12+
COMMENT ON COLUMN doma_panda.job_metrics.creationtime IS E'Time of data creation';
13+
COMMENT ON COLUMN doma_panda.job_metrics.modificationtime IS E'Time of last update';
14+
COMMENT ON COLUMN doma_panda.job_metrics.data IS E'Serialized dictionary of job metrics';
15+
ALTER TABLE doma_panda.job_metrics OWNER TO panda;
16+
ALTER TABLE doma_panda.job_metrics ADD PRIMARY KEY (pandaid, modificationtime);
17+
18+
CREATE TABLE doma_panda.task_metrics (
19+
"jeditaskid" BIGINT NOT NULL,
20+
"creationtime" TIMESTAMP,
21+
"modificationtime" TIMESTAMP,
22+
"data" TEXT
23+
) PARTITION BY RANGE (modificationtime);
24+
COMMENT ON TABLE doma_panda.task_metrics IS E'System metrics per task';
25+
COMMENT ON COLUMN doma_panda.task_metrics.jeditaskid IS E'JEDI task ID for the task';
26+
COMMENT ON COLUMN doma_panda.task_metrics.creationtime IS E'Time of data creation';
27+
COMMENT ON COLUMN doma_panda.task_metrics.modificationtime IS E'Time of last update';
28+
COMMENT ON COLUMN doma_panda.task_metrics.data IS E'Serialized dictionary of task metrics';
29+
ALTER TABLE doma_panda.task_metrics OWNER TO panda;
30+
ALTER TABLE doma_panda.task_metrics ADD PRIMARY KEY (jeditaskid, modificationtime);
31+
32+
33+
ALTER TABLE doma_panda.jedi_tasks
34+
ADD COLUMN "activatedtime" TIMESTAMP,
35+
ADD COLUMN "queuedtime" TIMESTAMP;
36+
COMMENT ON COLUMN doma_panda.jedi_tasks.activatedtime IS E'Time of activation processing workload';
37+
COMMENT ON COLUMN doma_panda.jedi_tasks.queuedtime IS E'Start time of queuing period ready to generate jobs';
38+
39+
ALTER TABLE doma_panda.config
40+
ADD COLUMN "value_json" JSONB;
41+
42+
-- Remove the constraint if it exists (PostgreSQL doesn't allow dropping unknown constraints without explicitly naming them)
43+
DO $$
44+
BEGIN
45+
IF EXISTS (
46+
SELECT 1
47+
FROM information_schema.table_constraints
48+
WHERE constraint_name = 'config_value_nn'
49+
AND table_name = 'config'
50+
) THEN
51+
ALTER TABLE doma_panda.config
52+
DROP CONSTRAINT config_value_nn;
53+
END IF;
54+
END $$;
55+
56+
SELECT partman.create_parent(
57+
p_parent_table => 'doma_panda.job_metrics',
58+
p_control => 'modificationtime',
59+
p_type => 'range',
60+
p_interval => '1 month',
61+
p_premake => 3
62+
);
63+
UPDATE partman.part_config
64+
SET infinite_time_partitions = true,
65+
retention = '12 months',
66+
retention_keep_table = false
67+
WHERE parent_table = 'doma_panda.job_metrics';
68+
69+
SELECT partman.create_parent(
70+
p_parent_table => 'doma_panda.task_metrics',
71+
p_control => 'modificationtime',
72+
p_type => 'range',
73+
p_interval => '1 month',
74+
p_premake => 3
75+
);
76+
UPDATE partman.part_config
77+
SET infinite_time_partitions = true,
78+
retention = '12 months',
79+
retention_keep_table = false
80+
WHERE parent_table = 'doma_panda.task_metrics';
81+
82+
-- Update versions
83+
UPDATE doma_panda.pandadb_version SET major=0, minor=0, patch=23 where component='JEDI';
84+
UPDATE doma_panda.pandadb_version SET major=0, minor=0, patch=23 where component='SERVER';
85+
COMMIT;

schema/postgres/sqls/pg_PANDA_TABLE.sql

Lines changed: 38 additions & 3 deletions
Original file line numberDiff line numberDiff line change
@@ -70,7 +70,8 @@ CREATE TABLE config (
7070
value varchar(256) NOT NULL,
7171
type varchar(64) NOT NULL,
7272
vo varchar(32) NOT NULL,
73-
descr varchar(256) NOT NULL
73+
descr varchar(256) NOT NULL,
74+
value_json JSONB
7475
) ;
7576
COMMENT ON TABLE config IS E'Central configuration table for jedi and panda server';
7677
COMMENT ON COLUMN config.app IS E'Application. E.g. jedi or pandaserver';
@@ -914,7 +915,9 @@ CREATE TABLE jedi_tasks (
914915
container_name varchar(200),
915916
job_label varchar(20),
916917
realmodificationtime timestamp,
917-
framework varchar(50)
918+
framework varchar(50),
919+
activatedtime timestamp,
920+
queuedtime timestamp
918921
) PARTITION BY RANGE (jeditaskid) ;
919922
COMMENT ON COLUMN jedi_tasks.amiflag IS E'It will contain a mask, one bit per AMI task (AMI has two tasks) with default value at insertion for "amiflag" to 3 (0b00000011). A trigger when the field “campaign” is modified: if "amiflag" is NULL then "amiflag" = 2 else "amiflag" = BITOR(AMIFLAG, 2)';
920923
COMMENT ON COLUMN jedi_tasks.architecture IS E'The architecture on which the task runs. Eg, $CMTCONFIG';
@@ -995,6 +998,8 @@ COMMENT ON COLUMN jedi_tasks.workdiskunit IS E'unit of WORKDISKCOUNT';
995998
COMMENT ON COLUMN jedi_tasks.workinggroup IS E'The name of the working group which owns the task ';
996999
COMMENT ON COLUMN jedi_tasks.workqueue_id IS E'The work queue identifier to which the task belongs';
9971000
COMMENT ON COLUMN jedi_tasks.framework IS E'Submission framework that was used to generate the task';
1001+
COMMENT ON COLUMN jedi_tasks.activatedtime IS E'Time of activation processing workload';
1002+
COMMENT ON COLUMN jedi_tasks.queuedtime IS E'Start time of queuing period ready to generate jobs';
9981003
ALTER TABLE jedi_tasks OWNER TO panda;
9991004
CREATE INDEX jedi_tasks_amiflag_idx ON jedi_tasks (amiflag);
10001005
CREATE INDEX jedi_tasks_creation_idx ON jedi_tasks (creationdate);
@@ -2798,7 +2803,7 @@ ALTER TABLE data_carousel_relations OWNER TO panda;
27982803
ALTER TABLE data_carousel_relations ADD PRIMARY KEY (request_id);
27992804

28002805
CREATE TABLE error_classification (
2801-
id BIGINT GENERATED ALWAYS AS IDENTITY (START WITH 1000000 INCREMENT BY 1) NOT NULL,
2806+
"id" BIGINT GENERATED ALWAYS AS IDENTITY (START WITH 1000000 INCREMENT BY 1) NOT NULL,
28022807
"error_source" VARCHAR(30) NOT NULL,
28032808
"error_code" bigint NOT NULL,
28042809
"error_diag" VARCHAR(256) NOT NULL,
@@ -2818,3 +2823,33 @@ COMMENT ON COLUMN error_classification.active IS E'Y or N. Depending on whether
28182823
COMMENT ON COLUMN error_classification.reg_date IS E'Registration date, defaults to current timestamp';ALTER TABLE error_classification OWNER TO panda;
28192824
ALTER TABLE error_classification OWNER TO panda;
28202825
ALTER TABLE error_classification ADD PRIMARY KEY (id);
2826+
2827+
CREATE TABLE job_metrics (
2828+
"pandaid" BIGINT NOT NULL,
2829+
"jeditaskid" BIGINT,
2830+
"creationtime" TIMESTAMP,
2831+
"modificationtime" TIMESTAMP,
2832+
"data" TEXT
2833+
) PARTITION BY RANGE (modificationtime);
2834+
COMMENT ON TABLE job_metrics IS E'System metrics per job';
2835+
COMMENT ON COLUMN job_metrics.pandaid IS E'PandaID for the job';
2836+
COMMENT ON COLUMN job_metrics.jeditaskid IS E'JEDI task ID for the job';
2837+
COMMENT ON COLUMN job_metrics.creationtime IS E'Time of data creation';
2838+
COMMENT ON COLUMN job_metrics.modificationtime IS E'Time of last update';
2839+
COMMENT ON COLUMN job_metrics.data IS E'Serialized dictionary of job metrics';
2840+
ALTER TABLE job_metrics OWNER TO panda;
2841+
ALTER TABLE job_metrics ADD PRIMARY KEY (pandaid, modificationtime);
2842+
2843+
CREATE TABLE task_metrics (
2844+
"jeditaskid" BIGINT NOT NULL,
2845+
"creationtime" TIMESTAMP,
2846+
"modificationtime" TIMESTAMP,
2847+
"data" TEXT
2848+
) PARTITION BY RANGE (modificationtime);
2849+
COMMENT ON TABLE task_metrics IS E'System metrics per task';
2850+
COMMENT ON COLUMN task_metrics.jeditaskid IS E'JEDI task ID for the task';
2851+
COMMENT ON COLUMN task_metrics.creationtime IS E'Time of data creation';
2852+
COMMENT ON COLUMN task_metrics.modificationtime IS E'Time of last update';
2853+
COMMENT ON COLUMN task_metrics.data IS E'Serialized dictionary of task metrics';
2854+
ALTER TABLE task_metrics OWNER TO panda;
2855+
ALTER TABLE task_metrics ADD PRIMARY KEY (jeditaskid, modificationtime);

0 commit comments

Comments
 (0)