diff --git a/schema/postgres/sqls/patches/0.0.19.patch.sql b/schema/postgres/sqls/patches/0.0.19.patch.sql new file mode 100644 index 0000000..34b20a5 --- /dev/null +++ b/schema/postgres/sqls/patches/0.0.19.patch.sql @@ -0,0 +1,80 @@ +-- patch to be used to upgrade from version 0.0.18 +ALTER TABLE doma_panda.mv_jobsactive4_stats ADD COLUMN num_of_cores bigint; +COMMENT ON COLUMN doma_panda.mv_jobsactive4_stats.num_of_cores IS E'Number of cores computed by grouping all set of attributes(columns) listed in that column'; + +CREATE OR REPLACE PROCEDURE doma_panda.update_jobsactive_stats () AS $body$ +BEGIN + +-- ver 1.3 , last modified on 2nd September 2024 +-- added NUM_OF_CORES columns +-- ver 1.2 , last modified on 2th July 2013 +-- added VO and WORKQUEUE_ID columns +-- to easy identify the session and better view on resource usage by setting a dedicated module for the PanDA jobs +--DBMS_APPLICATION_INFO.SET_MODULE( module_name => 'PanDA scheduler job', action_name => 'Aggregates data for the active jobs!'); +--DBMS_APPLICATION_INFO.SET_CLIENT_INFO( client_info => sys_context('userenv', 'host') || ' ( ' || sys_context('userenv', 'ip_address') || ' )' ); + + +DELETE from doma_panda.mv_jobsactive4_stats; + +INSERT INTO doma_panda.mv_jobsactive4_stats(CUR_DATE, + CLOUD, + COMPUTINGSITE, + COUNTRYGROUP, + WORKINGGROUP, + RELOCATIONFLAG, + JOBSTATUS, + PROCESSINGTYPE, + PRODSOURCELABEL, + CURRENTPRIORITY, + VO, + WORKQUEUE_ID, + NUM_OF_JOBS, + NUM_OF_CORES + ) + SELECT + clock_timestamp(), + cloud, + computingSite, + countrygroup, + workinggroup, + relocationflag, + jobStatus, + processingType, + prodSourceLabel, + TRUNC(currentPriority, -1) AS currentPriority, + VO, + WORKQUEUE_ID, + COUNT(*) AS num_of_jobs, + SUM(COALESCE(actualcorecount, corecount)) AS num_of_cores + FROM doma_panda.jobsActive4 + GROUP BY + clock_timestamp(), + cloud, + computingSite, + countrygroup, + workinggroup, + relocationflag, + jobStatus, + processingType, + prodSourceLabel, + TRUNC(currentPriority, -1), + VO, + WORKQUEUE_ID; +--COMMIT; + +--DBMS_APPLICATION_INFO.SET_MODULE( module_name => null, action_name => null); +--DBMS_APPLICATION_INFO.SET_CLIENT_INFO( client_info => null); + +end; +$body$ +LANGUAGE PLPGSQL +SECURITY DEFINER +; +ALTER PROCEDURE update_jobsactive_stats () OWNER TO panda; + + +-- Update versions +UPDATE doma_panda.pandadb_version SET major=0, minor=0, patch=19 where component='JEDI'; +UPDATE doma_panda.pandadb_version SET major=0, minor=0, patch=19 where component='SERVER'; +COMMIT; + diff --git a/schema/postgres/sqls/pg_PANDA_SCHEDULER_JOBS.sql b/schema/postgres/sqls/pg_PANDA_SCHEDULER_JOBS.sql index 2b533b8..23635ae 100644 --- a/schema/postgres/sqls/pg_PANDA_SCHEDULER_JOBS.sql +++ b/schema/postgres/sqls/pg_PANDA_SCHEDULER_JOBS.sql @@ -1221,6 +1221,8 @@ ALTER PROCEDURE tasks_statuslog_sl_window (DAYS_OFFSET bigint) owner TO panda; CREATE OR REPLACE PROCEDURE doma_panda.update_jobsactive_stats () AS $body$ BEGIN +-- ver 1.3 , last modified on 2nd September 2024 +-- added NUM_OF_CORES columns -- ver 1.2 , last modified on 2th July 2013 -- added VO and WORKQUEUE_ID columns -- to easy identify the session and better view on resource usage by setting a dedicated module for the PanDA jobs @@ -1242,7 +1244,8 @@ INSERT INTO mv_jobsactive4_stats(CUR_DATE, CURRENTPRIORITY, VO, WORKQUEUE_ID, - NUM_OF_JOBS + NUM_OF_JOBS, + NUM_OF_CORES ) SELECT clock_timestamp(), @@ -1257,7 +1260,8 @@ INSERT INTO mv_jobsactive4_stats(CUR_DATE, TRUNC(currentPriority, -1) AS currentPriority, VO, WORKQUEUE_ID, - COUNT(*) AS num_of_jobs + COUNT(*) AS num_of_jobs, + SUM(COALESCE(actualcorecount, corecount)) AS num_of_cores FROM jobsActive4 GROUP BY clock_timestamp(), diff --git a/schema/postgres/sqls/pg_PANDA_TABLE.sql b/schema/postgres/sqls/pg_PANDA_TABLE.sql index c4ea231..9ad38ae 100644 --- a/schema/postgres/sqls/pg_PANDA_TABLE.sql +++ b/schema/postgres/sqls/pg_PANDA_TABLE.sql @@ -2355,7 +2355,8 @@ CREATE TABLE mv_jobsactive4_stats ( currentpriority bigint, num_of_jobs bigint, vo varchar(32), - workqueue_id integer + workqueue_id integer, + num_of_cores bigint ) ; COMMENT ON TABLE mv_jobsactive4_stats IS E'Table (was from Materialized view before, but was not reliable) which collects aggregated data on set of attributes(columns). The data is read from the JOBSACTIVE4 table by an Oracle scheduler job. The refresh interval is 2 min'; COMMENT ON COLUMN mv_jobsactive4_stats.cloud IS E'cloud (associated with Tier 1) where the job is submitted to'; @@ -2369,6 +2370,7 @@ COMMENT ON COLUMN mv_jobsactive4_stats.processingtype IS E'type of the job comes COMMENT ON COLUMN mv_jobsactive4_stats.prodsourcelabel IS E'activity name of the name such as managed, user, and ddm'; COMMENT ON COLUMN mv_jobsactive4_stats.relocationflag IS E'flag for submitting jobs to a single site. I.e. the brokerage is bypassed'; COMMENT ON COLUMN mv_jobsactive4_stats.workinggroup IS E'working group name'; +COMMENT ON COLUMN mv_jobsactive4_stats.num_of_cores IS E'Number of cores computed by grouping all set of attributes(columns) listed in that column'; ALTER TABLE mv_jobsactive4_stats OWNER TO panda; ALTER TABLE mv_jobsactive4_stats ALTER COLUMN JOBSTATUS SET NOT NULL; diff --git a/schema/postgres/version b/schema/postgres/version index 32786aa..44517d5 100644 --- a/schema/postgres/version +++ b/schema/postgres/version @@ -1 +1 @@ -0.0.18 +0.0.19