Refresh MVWs daily

This commit is contained in:
Jan Kvetina 2022-07-02 10:14:28 +02:00
parent a39014458d
commit 80fda9cf7c
3 changed files with 65 additions and 0 deletions

View File

@ -0,0 +1,32 @@
DECLARE
in_job_name CONSTANT VARCHAR2(30) := 'CORE_REFRESH_MVIEWS';
in_run_immediatelly CONSTANT BOOLEAN := FALSE;
BEGIN
BEGIN
DBMS_SCHEDULER.DROP_JOB(in_job_name, TRUE);
EXCEPTION
WHEN OTHERS THEN
NULL;
END;
--
DBMS_SCHEDULER.CREATE_JOB (
job_name => in_job_name,
job_type => 'STORED_PROCEDURE',
job_action => 'app.refresh_mviews',
start_date => SYSDATE,
repeat_interval => 'FREQ=DAILY; BYHOUR=0; BYMINUTE=2', -- 00:02
enabled => FALSE,
comments => 'Refresh all existing materialized views'
);
--
DBMS_SCHEDULER.SET_ATTRIBUTE(in_job_name, 'JOB_PRIORITY', 3); -- normal priority
DBMS_SCHEDULER.ENABLE(in_job_name);
COMMIT;
--
IF in_run_immediatelly THEN
DBMS_SCHEDULER.RUN_JOB(in_job_name);
COMMIT;
END IF;
END;
/

View File

@ -1328,6 +1328,15 @@ CREATE OR REPLACE PACKAGE app AS
--
-- Refresh all materialized views
--
PROCEDURE refresh_mviews (
in_name_like VARCHAR2 := NULL
);
--
-- Returns procedure name which called this function with possible offset
--

View File

@ -3182,6 +3182,30 @@ CREATE OR REPLACE PACKAGE BODY app AS
PROCEDURE refresh_mviews (
in_name_like VARCHAR2 := NULL
)
AS
BEGIN
app.log_module(in_name_like);
--
FOR c IN (
SELECT m.mview_name
FROM user_mviews m
WHERE (m.mview_name LIKE in_name_like OR in_name_like IS NULL)
ORDER BY 1
) LOOP
DBMS_MVIEW.REFRESH(c.mview_name, 'C', parallelism => 1);
END LOOP;
--
app.log_success();
EXCEPTION
WHEN OTHERS THEN
app.raise_error();
END;
FUNCTION get_caller_name (
in_offset PLS_INTEGER := NULL
)