Files
Database/ADM/ADM_PAC.SRC
Alex Tiehuis 0c6068bcd4 FCLT#54336 adm.systrackscriptId gebruikt te kleine variabelen
svn path=/Database/trunk/; revision=38844
2018-08-16 15:28:10 +00:00

132 lines
4.8 KiB
Plaintext

/* $Revision$
* $Id$
*/
CREATE OR REPLACE PACKAGE adm
AS
PROCEDURE systrackscriptId (svnid IN VARCHAR2, force IN NUMBER DEFAULT 1);
PROCEDURE trydrop (n IN VARCHAR2);
PROCEDURE tryalter (n IN VARCHAR2);
FUNCTION scriptspoolfile (custpattern IN VARCHAR2, scriptname IN VARCHAR) RETURN VARCHAR;
END adm;
/
CREATE OR REPLACE PACKAGE BODY adm
AS
-- Voor SVN is dit handiger, vereist alleen de svn-id string
-- ($Id$)
PROCEDURE systrackscriptId (svnid IN VARCHAR2, force IN NUMBER DEFAULT 1)
AS
revisionnr adm_tracking.adm_tracking_revision%TYPE;
scriptname adm_tracking.adm_tracking_name%TYPE;
tempstr VARCHAR2 (100);
BEGIN
-- op het gemakje ontleden
tempstr := REPLACE (svnid, '$Id: ', '');
tempstr := RTRIM(SUBSTR(tempstr, 1, instr(tempstr, ' ', 1, 2)));
-- is nu: ADM_PAC.SRC 19151
scriptname := RTRIM(SUBSTR(tempstr, 1, instr(tempstr, ' ', 1, 1))); -- ADM_PAC
revisionnr := SUBSTR(tempstr, instr(tempstr, ' ', 1, 1) + 1); -- 19151
IF force = 1
THEN
INSERT INTO adm_tracking (adm_tracking_name, adm_tracking_revision)
VALUES (scriptname, revisionnr);
ELSE
BEGIN
UPDATE adm_tracking
SET adm_tracking_date = SYSDATE, adm_tracking_osuser = SYS_CONTEXT ('USERENV', 'OS_USER')
WHERE UPPER (adm_tracking_name) = UPPER (scriptname)
AND UPPER (adm_tracking_revision) = UPPER (revisionnr);
IF SQL%ROWCOUNT = 0
THEN
INSERT INTO adm_tracking (adm_tracking_name, adm_tracking_revision)
VALUES (scriptname, revisionnr);
END IF;
END;
END IF;
END;
-- DDL. Probeert een object (TABLE, INDEX e.d.) te droppen, maar moppert niet als die niet bestond
-- Hiermee voorkomen we foutmeldingen in logfiles die niet erg zijn
PROCEDURE trydrop (n IN VARCHAR2)
AS
stmt VARCHAR2 (1000);
BEGIN
stmt := 'DROP ' || n;
EXECUTE IMMEDIATE stmt;
DBMS_OUTPUT.put_line ('Found, successfully dropped: ' || n);
EXCEPTION
WHEN OTHERS
THEN
IF SQLCODE IN (-942, -1418, -2289, -4043, -4080)
THEN
-- did not exist, voor table, view, index, sequence, object and trigger
DBMS_OUTPUT.put_line ('Not found, no need to drop: ' || n);
NULL;
ELSE
raise_application_error (-20001, 'Error trying to DROP ' || n || ': ' || SQLERRM);
END IF;
END;
-- DDL. Probeert een object (TABLE, INDEX e.d.) te alteren, maar moppert niet als die niet bestond
-- Hiermee voorkomen we foutmeldingen in logfiles die niet erg zijn
PROCEDURE tryalter (n IN VARCHAR2)
AS
stmt VARCHAR2 (1000);
BEGIN
stmt := 'ALTER ' || n;
EXECUTE IMMEDIATE stmt;
DBMS_OUTPUT.put_line ('Found, successfully altered: ' || n);
EXCEPTION
WHEN OTHERS
THEN
IF SQLCODE IN (-904, -942, -1418, -2289, -4043, -4080, -2443)
THEN
-- did not exist, voor identifier (column) table, view, index, sequence, object and trigger, constraint
DBMS_OUTPUT.put_line ('Not found, not altered: ' || n);
NULL;
ELSIF SQLCODE IN (-955, -1442)
THEN
-- object or not-null property already exist
DBMS_OUTPUT.put_line ('Already exists, not altered: ' || n);
NULL;
ELSE
raise_application_error (-20001, 'Error trying to ALTER ' || n || ': ' || SQLERRM);
END IF;
END;
FUNCTION scriptspoolfile (custpattern IN VARCHAR2, -- eg ^SGGR for 'start with SGGR', ATCH|BONS for two schema
scriptname IN VARCHAR)
RETURN VARCHAR
IS
lstname VARCHAR2 (255);
tekst VARCHAR2 (255);
BEGIN
IF NOT REGEXP_LIKE(USER, custpattern, 'i') THEN
tekst := CHR(10) || '============================================' || CHR(10)
|| 'Wrong user!!!!!!!!!' || CHR(10)
|| 'User should be match ' || custpattern || ' but is ' || USER || CHR(10)
|| '============================================' || CHR(10);
RAISE_APPLICATION_ERROR(-20000, tekst);
END IF;
lstname := UPPER (scriptname);
RETURN lstname || '_'
|| UPPER( USER
|| '_'
|| SYS_CONTEXT ('USERENV', 'SERVICE_NAME')
|| '_'
|| SYS_CONTEXT ('USERENV', 'SERVER_HOST'))
|| '_'
|| TO_CHAR (SYSDATE, 'YYYYMMDD_HH24MISS')
|| '.lst';
END;
END adm;
/
REGISTERRUN('$Id$')