Commit dbdb1595 authored by Giuseppe Lo Presti's avatar Giuseppe Lo Presti
Browse files

CASTOR migration: one more iteration to include tape imports.

Moreover, the PL/SQL code for the CTA catalogue is temporarily
moved out of the catalogue folder as it requires some schema
changes that are still work in progress in a dev branch. Until
then, all migration code is evolved in the migration/ folder.
parent d6e874f8
-- commit any previous pending session
COMMIT;
--------------------------------------------------
-- 1. Usage stats. This section should be ported
-- to PostgreSQL at some time in the future.
--------------------------------------------------
-- Table for namespace statistics. Same logic as in CASTOR.
CREATE TABLE UsageStats (
gid NUMBER(6) DEFAULT 0 CONSTRAINT NN_UsageStats_gid NOT NULL,
timestamp NUMBER DEFAULT 0 CONSTRAINT NN_UsageStats_ts NOT NULL,
maxFileId INTEGER, fileCount INTEGER, fileSize INTEGER,
segCount INTEGER, segSize INTEGER, segCompressedSize INTEGER,
seg2Count INTEGER, seg2Size INTEGER, seg2CompressedSize INTEGER
);
ALTER TABLE UsageStats ADD CONSTRAINT PK_UsageStats_gid_ts PRIMARY KEY (gid, timestamp);
-- This table will be used to safely store the legacy CASTOR usage statistics.
CREATE TABLE CastorUsageStats (
gid NUMBER(6) DEFAULT 0 CONSTRAINT NN_UsageStats_gid NOT NULL,
timestamp NUMBER DEFAULT 0 CONSTRAINT NN_UsageStats_ts NOT NULL,
maxFileId INTEGER, fileCount INTEGER, fileSize INTEGER,
segCount INTEGER, segSize INTEGER, segCompressedSize INTEGER,
seg2Count INTEGER, seg2Size INTEGER, seg2CompressedSize INTEGER
);
-- This table is used to store the mapping gid -> experiment name, like in CASTOR.
-- Still to be manually updated, in the lack of an automated mechanism.
CREATE TABLE EXPERIMENTS (
NAME VARCHAR2(20 BYTE),
GID NUMBER(6,0) CONSTRAINT GID_PK PRIMARY KEY (GID)
);
-- Helper procedure to insert/accumulate statistics in the UsageStats table
CREATE OR REPLACE PROCEDURE insertNSStats(inGid IN INTEGER, inTimestamp IN NUMBER,
inMaxFileId IN INTEGER, inFileCount IN INTEGER, inFileSize IN INTEGER,
inSegCount IN INTEGER, inSegSize IN INTEGER, inSegCompressedSize IN INTEGER,
inSeg2Count IN INTEGER, inSeg2Size IN INTEGER, inSeg2CompressedSize IN INTEGER) AS
CONSTRAINT_VIOLATED EXCEPTION;
PRAGMA EXCEPTION_INIT(CONSTRAINT_VIOLATED, -1);
BEGIN
INSERT INTO UsageStats (gid, timestamp, maxFileId, fileCount, fileSize, segCount, segSize,
segCompressedSize, seg2Count, seg2Size, seg2CompressedSize)
VALUES (inGid, inTimestamp, inMaxFileId, inFileCount, inFileSize, inSegCount, inSegSize,
inSegCompressedSize, inSeg2Count, inSeg2Size, inSeg2CompressedSize);
EXCEPTION WHEN CONSTRAINT_VIOLATED THEN
UPDATE UsageStats SET
maxFileId = CASE WHEN inMaxFileId > maxFileId THEN inMaxFileId ELSE maxFileId END,
fileCount = fileCount + inFileCount,
fileSize = fileSize + inFileSize,
segCount = segCount + inSegCount,
segSize = segSize + inSegSize,
segCompressedSize = segCompressedSize + inSegCompressedSize,
seg2Count = seg2Count + inSeg2Count,
seg2Size = seg2Size + inSeg2Size,
seg2CompressedSize = seg2CompressedSize + inSeg2CompressedSize
WHERE gid = inGid AND timestamp = inTimestamp;
END;
/
-- This procedure is run as a database job to generate statistics from the namespace
-- Taken as is from CASTOR, cf. https://gitlab.cern.ch/castor/CASTOR/tree/master/ns/oracleTrailer.sql
CREATE OR REPLACE PROCEDURE gatherCatalogueStats AS
varTimestamp NUMBER := trunc(getTime());
BEGIN
-- File-level statistics
FOR g IN (SELECT disk_file_gid, MAX(archive_file_id) maxId,
COUNT(*) fileCount, SUM(size_in_bytes) fileSize
FROM Archive_File
WHERE creation_time < varTimestamp
GROUP BY disk_file_gid) LOOP
insertNSStats(g.disk_file_gid, varTimestamp, g.maxId, g.fileCount, g.fileSize, 0, 0, 0, 0, 0, 0);
END LOOP;
COMMIT;
-- Tape-level statistics
FOR g IN (SELECT disk_file_gid, copy_nb, SUM(size_in_bytes) segComprSize,
SUM(size_in_bytes) segSize, COUNT(*) segCount
FROM Tape_File, Archive_File
WHERE Tape_File.archive_file_id = Archive_File.archive_file_id
AND Archive_File.creation_time < varTimestamp
GROUP BY disk_file_gid, copy_nb) LOOP
IF g.copy_nb = 1 THEN
insertNSStats(g.disk_file_gid, varTimestamp, 0, 0, 0, g.segCount, g.segSize, g.segComprSize, 0, 0, 0);
ELSE
insertNSStats(g.disk_file_gid, varTimestamp, 0, 0, 0, 0, 0, 0, g.segCount, g.segSize, g.segComprSize);
END IF;
END LOOP;
COMMIT;
-- Also compute totals
INSERT INTO UsageStats (gid, timestamp, maxFileId, fileCount, fileSize, segCount, segSize,
segCompressedSize, seg2Count, seg2Size, seg2CompressedSize)
(SELECT -1, varTimestamp, MAX(maxFileId), SUM(fileCount), SUM(fileSize),
SUM(segCount), SUM(segSize), SUM(segCompressedSize),
SUM(seg2Count), SUM(seg2Size), SUM(seg2CompressedSize)
FROM UsageStats
WHERE timestamp = varTimestamp);
COMMIT;
END;
/
/* Database job for the statistics */
BEGIN
-- Remove database jobs before recreating them
FOR j IN (SELECT job_name FROM user_scheduler_jobs
WHERE job_name = 'STATSJOB')
LOOP
DBMS_SCHEDULER.DROP_JOB(j.job_name, TRUE);
END LOOP;
-- Create a db job to be run every day executing the gatherNSStats procedure
DBMS_SCHEDULER.CREATE_JOB(
JOB_NAME => 'StatsJob',
JOB_TYPE => 'PLSQL_BLOCK',
JOB_ACTION => 'BEGIN gatherCatalogueStats(); END;',
JOB_CLASS => 'CASTOR_JOB_CLASS',
START_DATE => SYSDATE + 60/1440,
REPEAT_INTERVAL => 'FREQ=DAILY; INTERVAL=1',
ENABLED => TRUE,
COMMENTS => 'Gathering of catalogue usage statistics');
END;
/
---------------------------------------------
-- 2. CASTOR to CTA migration. This code is
-- only supported for Oracle.
---------------------------------------------
-- Create synonyms for all relevant tables
-- XXX TBD XXX
-- Import metadata from the CASTOR namespace
CREATE OR REPLACE importFromCASTOR(inTapePool VARCHAR2, inEOSCTAInstance VARCHAR2,
Dirs OUT SYS_REFCURSOR, Files OUT SYS_REFCURSOR) AS
nbFiles INTEGER;
pathInEos VARCHAR2;
ct INTEGER := 0;
BEGIN
-- XXX error handling is missing
castor.prepareCTAExport(inTapePool, nbFiles);
castor.dirsForCTAExport(inTapePool);
-- Get all metadata for the EOS-side namespace
OPEN Dirs FOR
SELECT *
FROM castor.CTADirsHelper;
castor.filesForCTAExport(inTapePool);
OPEN Files FOR
SELECT *
FROM castor.CTAFilesHelper;
END;
/
CREATE OR REPLACE populateCTAFromCASTOR AS
BEGIN
-- Populate the CTA catalogue with the CASTOR file/tape metadata
FOR f IN (SELECT * FROM castor.CTAFilesHelper) LOOP
pathInEos := '/eos/cta/' || inEOSCTAInstance || f.path; -- XXX how to massage this?
-- insert file metadata
INSERT INTO Archive_File (archive_file_id, disk_instance_name, disk_file_id, disk_file_path,
disk_gid, size_in_bytes, checksum_type, checksum_value,
storage_class_id, creation_time, reconciliation_time)
VALUES (f.fileId, inEOSCTAInstance, f.fileId, pathInEos, f.gid,
f.filesize, 'AD', f.checksum, f.fileclass, f.atime, 0);
-- insert tape metadata
INSERT INTO Tape_File (archive_file_id, vid, fseq, block_id, copy_nb, creation_time)
VALUES (f.fileId, f.vid, f.fseq, f.blockId, f.copyno, f.s_mtime);
IF ct = 10000 THEN
COMMIT;
ct := 0;
END IF;
ct := ct + 1;
END LOOP;
END;
/
CREATE OR REPLACE completeImportFromCASTOR AS
BEGIN
castor.completeCTAExport;
END;
/
/*****************************************************************************
* castor_ctamigration_schema.sql
* castorns_ctamigration_schema.sql
*
* This file is part of the Castor/CTA project.
* See http://castor.web.cern.ch/castor
......@@ -27,100 +27,75 @@
UNDEF ctaSchema
ACCEPT ctaSchema CHAR PROMPT 'Enter the name of the CTA schema: ';
-- Table for the CTA export
CREATE TABLE CTAExport (fileid INTEGER NOT NULL PRIMARY KEY);
-- Need to grant access from the CTA catalogue schema
GRANT SELECT ON CTAExport TO &ctaSchema;
-- Tables to store intermediate data for the export.
-- As above we cannot use temporary tables with distributed transactions.
-- Helper tables to store intermediate data for the export.
-- We cannot use temporary tables with distributed transactions.
CREATE TABLE CTAFilesHelper (fileid INTEGER NOT NULL PRIMARY KEY, path VARCHAR2(2048), disk_uid INTEGER, disk_gid INTEGER,
filemode INTEGER, atime INTEGER, mtime INTEGER, fileclass INTEGER,
filemode INTEGER, atime INTEGER, mtime INTEGER, classname VARCHAR2(100),
filesize INTEGER, checksum VARCHAR2(10), copyno INTEGER, VID VARCHAR2(6), fseq INTEGER,
blockId INTEGER, s_mtime INTEGER);
GRANT SELECT ON CTAFilesHelper TO &ctaSchema;
CREATE TABLE CTADirsHelper (fileid INTEGER NOT NULL PRIMARY KEY, path VARCHAR2(2048), disk_uid INTEGER, disk_gid INTEGER,
filemode INTEGER, atime INTEGER, mtime INTEGER, fileclass INTEGER);
filemode INTEGER, atime INTEGER, mtime INTEGER, classname VARCHAR2(100));
-- Need to grant access from the CTA catalogue schema
GRANT SELECT ON CTAFilesHelper TO &ctaSchema;
GRANT SELECT ON CTADirsHelper TO &ctaSchema;
/* Procedure to extract the directory names for the export to CTA */
CREATE OR REPLACE PROCEDURE dirsForCTAExport(inPoolName IN VARCHAR2) AS
CREATE OR REPLACE PROCEDURE filesAndDirsForCTAExport(inPoolName IN VARCHAR2) AS
fileids numList;
dirids numList;
nbFiles INTEGER;
BEGIN
SELECT DISTINCT(F.parent_fileid)
BULK COLLECT INTO fileids
-- First check if there's anything already ongoing and fail early:
SELECT COUNT(*) INTO nbFiles FROM CTAFilesHelper;
IF nbFiles > 0 THEN
raise_application_error(-20000, 'Another export of ' || nbFiles || ' files to CTA is ongoing, ' ||
'please terminate it with completeCTAExport() before starting a new one.');
END IF;
-- Run the minimal join query to extract all relevant fileids and log this number
SELECT F.fileid, F.parent_fileid
BULK COLLECT INTO fileids, dirids
FROM Cns_file_metadata F, Cns_seg_metadata S
WHERE F.fileid = S.s_fileid
AND vid IN (
SELECT vid FROM Vmgr_tape_side
WHERE poolName = inPoolName AND BITAND(status, 2) = 0 -- not already EXPORTED
);
-- XXX TODO log fileids.LENGTH
-- Populate the helper tables by selecting all required metadata
EXECUTE IMMEDIATE 'TRUNCATE TABLE CTADirsHelper';
INSERT /*+ APPEND */ INTO CTADirsHelper (
-- strip the /castor/cern.ch prefix from all paths
SELECT F.fileid, substr(nvl(D.path, getPathForFileid(F.fileid)), length('/castor/cern.ch')) as path,
F.owner_uid disk_uid, F.gid disk_gid,
F.filemode, F.atime, F.mtime, F.fileclass -- XXX fileclass?
FROM Cns_file_metadata F, Dirs_Full_Path D,
(SELECT * FROM TABLE(fileids)) DirIds
WHERE DirIds.column_value = F.fileid
AND F.fileid(+) = D.fileid);
END;
/
/* Procedure to prepare the export to CTA */
CREATE OR REPLACE PROCEDURE prepareCTAExport(inPoolName IN VARCHAR2, nbFiles OUT INTEGER) AS
nbAlreadyExported INTEGER;
BEGIN
-- check if there's some ongoing export
SELECT COUNT(*) INTO nbFiles FROM CTAExport;
IF nbFiles > 0 THEN
raise_application_error(-20000, 'Another export of ' || nbFiles || ' files to CTA is ongoing, ' ||
'please terminate it with completeCTAExport() before starting a new one.');
END IF;
-- first extract the tape pool and tapes metadata
-- now prepare the files
INSERT /*+ APPEND */ INTO CTAExport (
SELECT s_fileid FROM Cns_seg_metadata WHERE vid IN (
SELECT vid FROM Vmgr_tape_side
WHERE poolName = inPoolName AND BITAND(status, 2) = 0 -- not already EXPORTED
));
-- check if some files had already been exported
SELECT COUNT(*) INTO nbAlreadyExported FROM Cns_file_metadata F, CTAExport
WHERE F.fileid = CTAExport.fileid
AND F.onCTA = 1;
IF nbFiles > 0 THEN
raise_application_error(-20000, 'Warning: found ' || nbAlreadyExported || ' already exported, please manually check them.');
END IF;
-- all right, return the count of files to be exported
SELECT COUNT(*) INTO nbFiles FROM CTAExport;
END;
/
/* Procedure to extract the files metadata for the export to CTA */
CREATE OR REPLACE PROCEDURE filesForCTAExport(inPoolName IN VARCHAR2) AS
BEGIN
EXECUTE IMMEDIATE 'TRUNCATE TABLE CTAFilesHelper';
F.filemode, F.atime, F.mtime, C.name classname
FROM Cns_file_metadata F, Cns_class_metadata C, Dirs_Full_Path D,
(SELECT * FROM TABLE(dirIds)) DirIdsTable
WHERE DirIdsTable.column_value = F.fileid
AND F.fileid(+) = D.fileid
);
COMMIT;
INSERT /*+ APPEND */ INTO CTAFilesHelper (
SELECT F.fileid, decode(D.path, NULL, getPathForFileid(F.fileid), D.path || '/' || F.name) as path,
F.owner_uid, F.gid, F.filemode, F.atime, F.mtime, F.fileclass,
F.owner_uid, F.gid, F.filemode, F.atime, F.mtime, C.name classname,
S.segsize, S.checksum, S.copyno, S.vid, S.fseq, utl_raw.cast_to_binary_integer(S.blockId),
S.lastModificationTime as s_mtime
FROM Cns_file_metadata F, Cns_seg_metadata S, Cns_class_metadata C, Dirs_Full_Path D, CTAExport
WHERE CTAExport.fileid = F.fileid
FROM Cns_file_metadata F, Cns_seg_metadata S, Cns_class_metadata C, Dirs_Full_Path D,
(SELECT * FROM TABLE(fileIds)) FileIdsTable
WHERE F.fileid = FileIdsTable.column_value
AND F.fileid = S.s_fileid
AND F.parent_fileid(+) = D.fileid
AND F.fileclass = C.classid
);
COMMIT;
END;
/
/* Procedure to terminate the export to CTA and account it on the statistics */
CREATE OR REPLACE PROCEDURE completeCTAExport(inPoolName IN VARCHAR2) AS
CURSOR c IS SELECT fileid FROM CTAExport;
CURSOR c IS SELECT fileid FROM CTAFilesHelper;
ids numList;
BEGIN
LOOP
......@@ -133,10 +108,10 @@ BEGIN
FORALL i IN 1..ids.count
UPDATE Cns_seg_metadata SET onCTA = 1 WHERE s_fileid = ids(i);
FORALL i IN 1..ids.count
DELETE FROM CTAExport WHERE fileid = ids(i);
DELETE FROM CTAFilesHelper WHERE fileid = ids(i);
COMMIT;
END LOOP;
EXECUTE IMMEDIATE 'TRUNCATE TABLE CTAExport';
EXECUTE IMMEDIATE 'TRUNCATE TABLE CTAFilesHelper';
END;
/
......
-- commit any previous pending session
COMMIT;
--------------------------------------------------
-- 1. Usage stats. This section should be ported
-- to PostgreSQL at some time in the future.
--------------------------------------------------
-- Table for namespace statistics. Same logic as in CASTOR.
CREATE TABLE UsageStats (
gid NUMBER(6) DEFAULT 0 CONSTRAINT NN_UsageStats_gid NOT NULL,
timestamp NUMBER DEFAULT 0 CONSTRAINT NN_UsageStats_ts NOT NULL,
maxFileId INTEGER, fileCount INTEGER, fileSize INTEGER,
segCount INTEGER, segSize INTEGER, segCompressedSize INTEGER,
seg2Count INTEGER, seg2Size INTEGER, seg2CompressedSize INTEGER
);
ALTER TABLE UsageStats ADD CONSTRAINT PK_UsageStats_gid_ts PRIMARY KEY (gid, timestamp);
-- This table will be used to safely store the legacy CASTOR usage statistics.
CREATE TABLE CastorUsageStats (
gid NUMBER(6) DEFAULT 0 CONSTRAINT NN_UsageStats_gid NOT NULL,
timestamp NUMBER DEFAULT 0 CONSTRAINT NN_UsageStats_ts NOT NULL,
maxFileId INTEGER, fileCount INTEGER, fileSize INTEGER,
segCount INTEGER, segSize INTEGER, segCompressedSize INTEGER,
seg2Count INTEGER, seg2Size INTEGER, seg2CompressedSize INTEGER
);
-- This table is used to store the mapping gid -> experiment name, like in CASTOR.
-- Still to be manually updated, in the lack of an automated mechanism.
CREATE TABLE EXPERIMENTS (
NAME VARCHAR2(20 BYTE),
GID NUMBER(6,0) CONSTRAINT GID_PK PRIMARY KEY (GID)
);
-- Helper procedure to insert/accumulate statistics in the UsageStats table
CREATE OR REPLACE PROCEDURE insertNSStats(inGid IN INTEGER, inTimestamp IN NUMBER,
inMaxFileId IN INTEGER, inFileCount IN INTEGER, inFileSize IN INTEGER,
inSegCount IN INTEGER, inSegSize IN INTEGER, inSegCompressedSize IN INTEGER,
inSeg2Count IN INTEGER, inSeg2Size IN INTEGER, inSeg2CompressedSize IN INTEGER) AS
CONSTRAINT_VIOLATED EXCEPTION;
PRAGMA EXCEPTION_INIT(CONSTRAINT_VIOLATED, -1);
BEGIN
INSERT INTO UsageStats (gid, timestamp, maxFileId, fileCount, fileSize, segCount, segSize,
segCompressedSize, seg2Count, seg2Size, seg2CompressedSize)
VALUES (inGid, inTimestamp, inMaxFileId, inFileCount, inFileSize, inSegCount, inSegSize,
inSegCompressedSize, inSeg2Count, inSeg2Size, inSeg2CompressedSize);
EXCEPTION WHEN CONSTRAINT_VIOLATED THEN
UPDATE UsageStats SET
maxFileId = CASE WHEN inMaxFileId > maxFileId THEN inMaxFileId ELSE maxFileId END,
fileCount = fileCount + inFileCount,
fileSize = fileSize + inFileSize,
segCount = segCount + inSegCount,
segSize = segSize + inSegSize,
segCompressedSize = segCompressedSize + inSegCompressedSize,
seg2Count = seg2Count + inSeg2Count,
seg2Size = seg2Size + inSeg2Size,
seg2CompressedSize = seg2CompressedSize + inSeg2CompressedSize
WHERE gid = inGid AND timestamp = inTimestamp;
END;
/
-- This procedure is run as a database job to generate statistics from the namespace
-- Taken as is from CASTOR, cf. https://gitlab.cern.ch/castor/CASTOR/tree/master/ns/oracleTrailer.sql
CREATE OR REPLACE PROCEDURE gatherCatalogueStats AS
varTimestamp NUMBER := trunc(getTime());
BEGIN
-- File-level statistics
FOR g IN (SELECT disk_file_gid, MAX(archive_file_id) maxId,
COUNT(*) fileCount, SUM(size_in_bytes) fileSize
FROM Archive_File
WHERE creation_time < varTimestamp
GROUP BY disk_file_gid) LOOP
insertNSStats(g.disk_file_gid, varTimestamp, g.maxId, g.fileCount, g.fileSize, 0, 0, 0, 0, 0, 0);
END LOOP;
COMMIT;
-- Tape-level statistics
FOR g IN (SELECT disk_file_gid, copy_nb, SUM(size_in_bytes) segComprSize,
SUM(size_in_bytes) segSize, COUNT(*) segCount
FROM Tape_File, Archive_File
WHERE Tape_File.archive_file_id = Archive_File.archive_file_id
AND Archive_File.creation_time < varTimestamp
GROUP BY disk_file_gid, copy_nb) LOOP
IF g.copy_nb = 1 THEN
insertNSStats(g.disk_file_gid, varTimestamp, 0, 0, 0, g.segCount, g.segSize, g.segComprSize, 0, 0, 0);
ELSE
insertNSStats(g.disk_file_gid, varTimestamp, 0, 0, 0, 0, 0, 0, g.segCount, g.segSize, g.segComprSize);
END IF;
END LOOP;
COMMIT;
-- Also compute totals
INSERT INTO UsageStats (gid, timestamp, maxFileId, fileCount, fileSize, segCount, segSize,
segCompressedSize, seg2Count, seg2Size, seg2CompressedSize)
(SELECT -1, varTimestamp, MAX(maxFileId), SUM(fileCount), SUM(fileSize),
SUM(segCount), SUM(segSize), SUM(segCompressedSize),
SUM(seg2Count), SUM(seg2Size), SUM(seg2CompressedSize)
FROM UsageStats
WHERE timestamp = varTimestamp);
COMMIT;
END;
/
/* Database job for the statistics */
BEGIN
-- Remove database jobs before recreating them
FOR j IN (SELECT job_name FROM user_scheduler_jobs
WHERE job_name = 'STATSJOB')
LOOP
DBMS_SCHEDULER.DROP_JOB(j.job_name, TRUE);
END LOOP;
-- Create a db job to be run every day executing the gatherNSStats procedure
DBMS_SCHEDULER.CREATE_JOB(
JOB_NAME => 'StatsJob',
JOB_TYPE => 'PLSQL_BLOCK',
JOB_ACTION => 'BEGIN gatherCatalogueStats(); END;',
JOB_CLASS => 'CASTOR_JOB_CLASS',
START_DATE => SYSDATE + 60/1440,
REPEAT_INTERVAL => 'FREQ=DAILY; INTERVAL=1',
ENABLED => TRUE,
COMMENTS => 'Gathering of catalogue usage statistics');
END;
/
---------------------------------------------
-- 2. CASTOR to CTA migration. This code is
-- only supported for Oracle.
---------------------------------------------
-- Create synonyms for all relevant tables
-- XXX TBD XXX
/* Function to convert seconds into a time string using the format:
* DD-MON-YYYY HH24:MI:SS. If seconds is not defined then the current time
* will be returned. Note that the time is converted from UTC to the
* currently defined time zone.
*/
CREATE OR REPLACE FUNCTION getTimeString
(seconds IN NUMBER DEFAULT NULL,
format IN VARCHAR2 DEFAULT 'DD-MON-YYYY HH24:MI:SS')
RETURN VARCHAR2 AS
BEGIN
RETURN (to_char(to_date('01-JAN-1970', 'DD-MON-YYYY') + (systimestamp - cast(sys_extract_utc(systimestamp) as date))
+ nvl(seconds, getTime()) / (60 * 60 * 24), format));
END;
/
-- Import metadata from the CASTOR namespace
CREATE OR REPLACE PROCEDURE importFromCASTOR(inTapePool VARCHAR2, inVO VARCHAR2, inEOSCTAInstance VARCHAR2,
Dirs OUT SYS_REFCURSOR, Files OUT SYS_REFCURSOR) AS
BEGIN
-- first import tapes
importTapePool(inTapePool, inVO);
-- XXX error handling is missing
castor.filesAndDirsForCTAExport(inTapePool);
-- import metadata into the CTA catalogue
populateCTAFromCASTOR(inEOSCTAInstance);
-- Get all metadata for the EOS-side namespace
OPEN Dirs FOR
SELECT * FROM castor.CTADirsHelper;
OPEN Files FOR
SELECT * FROM castor.CTAFilesHelper;
END;
/
CREATE OR REPLACE PROCEDURE populateCTAFromCASTOR(inEOSCTAInstance VARCHAR2) AS
pathInEos VARCHAR2;
ct INTEGER := 0;
BEGIN
-- Populate the CTA catalogue with the CASTOR file/tape metadata
FOR f IN (SELECT * FROM castor.CTAFilesHelper) LOOP
pathInEos := '/eos/cta/' || inEOSCTAInstance || f.path; -- XXX how to massage this?
-- insert file metadata
INSERT INTO Archive_File (archive_file_id, disk_instance_name, disk_file_id, disk_file_path,
disk_gid, size_in_bytes, checksum_type, checksum_value,
storage_class_id, creation_time, reconciliation_time)
VALUES (f.fileId, inEOSCTAInstance, f.fileId, pathInEos, f.gid,
f.filesize, 'AD', f.checksum, f.classname, f.atime, 0);
-- insert tape metadata
INSERT INTO Tape_File (archive_file_id, vid, fseq, block_id, copy_nb, creation_time)
VALUES (f.fileId, f.vid, f.fseq, f.blockId, f.copyno, f.s_mtime);
-- update data counter on the Tape table. This does NOT include deleted segments,
-- but it's the best approximation we have here.
UPDATE Tape
SET data_in_bytes = data_in_bytes + f.filesize
WHERE vid = f.vid;
IF ct = 10000 THEN
COMMIT;
ct := 0;
END IF;
ct := ct + 1;
END LOOP;
COMMIT;
END;
/
-- Import a tapepool and its tapes from CASTOR
-- Raises constraint_violation if the tapepool and/or some tapes were already imported
CREATE OR REPLACE PROCEDURE importTapePool(inTapePool VARCHAR2, inVO VARCHAR2) AS
BEGIN
INSERT INTO Tape_Pool (tape_pool_name, vo, nb_partial_tapes, is_encrypted, user_comment,
creation_log_user_name, creation_log_host_name, creation_log_time, last_update_user_name,
last_update_host_name, last_update_time) VALUES (
inTapePool,
inVO,
0, -- nb_partial_tapes?
'F',
'Imported from CASTOR',
'CASTOR', 'CASTOR', getTime,
'CASTOR', 'CASTOR', getTime
);
FOR T in (SELECT T.vid, T.library, TS.status, TS.nbfiles
FROM castor.Vmgr_tape_info T, castor.Vmgr_tape_side TS
WHERE T.vid = TS.vid and TS.poolname = 'r_' || inTapePool) LOOP
INSERT INTO Tape (vid, media_type, vendor, logical_library_name, tape_pool_name,
encryption_key, capacity_in_bytes, data_in_bytes, last_fseq, is_disabled, is_full,
label_drive, label_time, last_read_drive, last_read_time, last_write_drive, last_write_time,
user_comment, creation_log_user_name, creation_log_host_name, creation_log_time,
last_update_user_name, last_update_host_name, last_update_time) VALUES (
T.vid,
'', '', -- media_type & vendor from model/media_letter/manufacturer
T.library,
inTapePool,
'',
0, -- capacity?
0, -- data: will be filled afterwards
0, -- last_fseq?
False,
BITAND(TS.status, "FULL") > 0, -- XXX find the right value for FULL
'CASTOR', 0, -- label_drive and time
'CASTOR', 0, -- last read drive and time
'CASTOR', 0, -- last write drive and time
'Imported from CASTOR',
'CASTOR', 'CASTOR', getTime,
'CASTOR', 'CASTOR', getTime
);
END LOOP;
COMMIT;
END;
/