Skip to content
Snippets Groups Projects
Commit 219d0006 authored by Steven Murray's avatar Steven Murray
Browse files

drop_oracle_schema.sql aborts if schema is LOCKED

parent ad1ee78f
No related branches found
No related tags found
No related merge requests found
CREATE TABLE CTA_CATALOGUE(
SCHEMA_STATUS VARCHAR2(100) NOT NULL,
SCHEMA_VERSION_MAJOR INTEGER NOT NULL,
SCHEMA_VERSION_MINOR INTEGER NOT NULL,
CONSTRAINT CTA_SCHEMA_STATUS_CK CHECK(SCHEMA_STATUS IN ('LOCKED', 'UNLOCKED'))
);
CREATE TABLE ADMIN_USER(
ADMIN_USER_NAME VARCHAR2(100) NOT NULL,
USER_COMMENT VARCHAR2(1000) NOT NULL,
......@@ -45,7 +51,7 @@ CREATE TABLE TAPE_POOL(
LAST_UPDATE_HOST_NAME VARCHAR2(100) NOT NULL,
LAST_UPDATE_TIME INTEGER NOT NULL,
CONSTRAINT TAPE_POOL_PK PRIMARY KEY(TAPE_POOL_NAME),
CONSTRAINT TAPE_POOL_IS_ENCRYPTED_BOOL_CK CHECK(IS_ENCRYPTED = 0 OR IS_ENCRYPTED = 1)
CONSTRAINT TAPE_POOL_IS_ENCRYPTED_BOOL_CK CHECK(IS_ENCRYPTED IN (0, 1))
);
CREATE TABLE ARCHIVE_ROUTE(
DISK_INSTANCE_NAME VARCHAR2(100) NOT NULL,
......@@ -189,3 +195,11 @@ CREATE TABLE TAPE_FILE(
CONSTRAINT TAPE_FILE_VID_BLOCK_ID_UN UNIQUE(VID, BLOCK_ID),
CONSTRAINT TAPE_FILE_VID_ARCH_FILE_ID_UN UNIQUE(VID, ARCHIVE_FILE_ID)
);
INSERT INTO CTA_CATALOGUE(
SCHEMA_STATUS,
SCHEMA_VERSION_MAJOR,
SCHEMA_VERSION_MINOR)
VALUES(
'LOCKED',
0,
0);
WHENEVER SQLERROR EXIT 1
CREATE SEQUENCE ARCHIVE_FILE_ID_SEQ
INCREMENT BY 1
START WITH 0
......
COMMIT;
QUIT
DROP TABLE ARCHIVE_ROUTE;
DROP TABLE TAPE_FILE;
DROP TABLE ARCHIVE_FILE;
DROP TABLE TAPE;
DROP TABLE REQUESTER_MOUNT_RULE;
DROP TABLE REQUESTER_GROUP_MOUNT_RULE;
DROP TABLE ADMIN_USER;
DROP TABLE ADMIN_HOST;
DROP TABLE STORAGE_CLASS;
DROP TABLE TAPE_POOL;
DROP TABLE LOGICAL_LIBRARY;
DROP TABLE MOUNT_POLICY;
DROP SEQUENCE ARCHIVE_FILE_ID_SEQ;
QUIT
WHENEVER SQLERROR EXIT 1
SET SERVEROUTPUT ON
SET FEEDBACK OFF
VARIABLE plSqlReturnValue NUMBER
DECLARE
SchemaIsLockedException EXCEPTION;
TYPE NameList IS TABLE OF VARCHAR2(30);
tables NameList := NameList(
'CTA_CATALOGUE',
'ARCHIVE_ROUTE',
'TAPE_FILE',
'ARCHIVE_FILE',
'TAPE',
'REQUESTER_MOUNT_RULE',
'REQUESTER_GROUP_MOUNT_RULE',
'ADMIN_USER',
'ADMIN_HOST',
'STORAGE_CLASS',
'TAPE_POOL',
'LOGICAL_LIBRARY',
'MOUNT_POLICY');
sequences NameList := NameList(
'ARCHIVE_FILE_ID_SEQ');
PROCEDURE dropTableIfExists(tableName IN VARCHAR2) IS
BEGIN
EXECUTE IMMEDIATE 'DROP TABLE ' || tableNAme;
DBMS_OUTPUT.PUT_LINE('Table ' || tableName || ' dropped');
EXCEPTION
WHEN OTHERS THEN
-- ORA-00942: table or view does not exis
IF SQLCODE = -942 THEN
DBMS_OUTPUT.PUT_LINE('Table ' || tableName || ' not dropped because it does not exist');
ELSE
RAISE;
END IF;
END;
PROCEDURE dropSequenceIfExists(sequenceName IN VARCHAR2) IS
BEGIN
EXECUTE IMMEDIATE 'DROP SEQUENCE ' || sequenceName;
DBMS_OUTPUT.PUT_LINE('Sequence ' || sequenceName || ' dropped');
EXCEPTION
WHEN OTHERS THEN
-- ORA-02289: sequence does not exist
IF SQLCODE = -2289 THEN
DBMS_OUTPUT.PUT_LINE('Sequence ' || sequenceName || ' not dropped because it does not exist');
ELSE
RAISE;
END IF;
END;
FUNCTION catalogueSchemaIsLocked RETURN BOOLEAN IS
TYPE StatusList IS TABLE OF VARCHAR(100);
schemaLocked INTEGER;
schemaStatus VARCHAR(100);
BEGIN
EXECUTE IMMEDIATE 'SELECT SCHEMA_STATUS FROM CTA_CATALOGUE' INTO schemaStatus;
RETURN 'LOCKED' = schemaStatus;
EXCEPTION
WHEN NO_DATA_FOUND THEN
DBMS_OUTPUT.PUT_LINE('Catalogue schema considered LOCKED because CTA_CATALOGUE table is corrupted');
DBMS_OUTPUT.PUT_LINE('CTA_CATALOGUE table is empty when it should contain one row');
RETURN TRUE;
WHEN OTHERS THEN
DBMS_OUTPUT.PUT_LINE('SQLCODE=' || SQLCODE);
-- ORA-00942: table or view does not exis
IF SQLCODE = -942 THEN
DBMS_OUTPUT.PUT_LINE('Catalogue schema considered UNLOCKED because the CTA_CATALOGUE table does not exist');
RETURN FALSE;
-- ORA-01422: exact fetch returns more than requested number of rows
ELSIF SQLCODE = -1422 THEN
DBMS_OUTPUT.PUT_LINE('Catalogue schema considered LOCKED because CTA_CATALOGUE table is corrupted');
DBMS_OUTPUT.PUT_LINE('CTA_CATALOGUE table contains more than one row when it should contain one');
RETURN TRUE;
ELSE
RAISE;
END IF;
END;
BEGIN
-- Non-zero means failure
:plSqlReturnValue := 1;
IF catalogueSchemaIsLocked() THEN
DBMS_OUTPUT.PUT_LINE('Aborting drop of catalogue schema objects: Schema is LOCKED');
ELSE
FOR i IN 1 .. tables.COUNT LOOP
dropTableIfExists(tables(i));
END LOOP;
FOR i IN 1 .. sequences.COUNT LOOP
dropSequenceIfExists(sequences(i));
END LOOP;
-- Zero means success
:plSqlReturnValue := 0;
END IF;
END;
/
EXIT :plSqlReturnValue
DROP TABLE CTA_CATALOGUE;
DROP TABLE ARCHIVE_ROUTE;
DROP TABLE TAPE_FILE;
DROP TABLE ARCHIVE_FILE;
......
0% Loading or .
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment