sql_txt := 'CREATE TABLE Requests (subreqid CHAR(36) NOT NULL PRIMARY KEY, timestamp DATE NOT NULL, reqid CHAR(36) NOT NULL, nsfileid NUMBER NOT NULL, type VARCHAR2(255), svcclass VARCHAR2(255), username VARCHAR2(255), state VARCHAR2(255),filename VARCHAR2(2048), filesize NUMBER)
PARTITION BY RANGE (timestamp) (PARTITION ' ||CreationDate || ' VALUES LESS THAN ( to_date('''||ts_var||''',''DD-MON-YYYY'')))';
execute immediate sql_txt;
commit;
sql_txt := 'CREATE TABLE internalDiskCopy (timestamp DATE NOT NULL,svcclass VARCHAR2(255), copies NUMBER)
PARTITION BY RANGE (timestamp) (PARTITION ' ||CreationDate || ' VALUES LESS THAN ( to_date('''||ts_var||''',''DD-MON-YYYY'')))';
execute immediate sql_txt;
commit;
sql_txt := 'CREATE TABLE Errors (timestamp DATE NOT NULL,reqid CHAR(36) NOT NULL,subreqid CHAR(36) NOT NULL,facility NUMBER, msg_no NUMBER)
PARTITION BY RANGE (timestamp) (PARTITION ' ||CreationDate || ' VALUES LESS THAN ( to_date('''||ts_var||''',''DD-MON-YYYY'')))';
execute immediate sql_txt;
commit;
sql_txt := 'CREATE TABLE TotalLatency (subreqid CHAR(36) NOT NULL PRIMARY KEY, timestamp DATE NOT NULL,nsfileid NUMBER NOT NULL, totallatency NUMBER)
PARTITION BY RANGE (timestamp) (PARTITION ' ||CreationDate || ' VALUES LESS THAN ( to_date('''||ts_var||''',''DD-MON-YYYY'')))';
execute immediate sql_txt;
commit;
sql_txt := 'CREATE TABLE TapeRecall( subreqid CHAR(36) NOT NULL PRIMARY KEY,timestamp DATE NOT NULL, TapeId VARCHAR2(255 BYTE), TapeMountState VARCHAR2(255 BYTE),ReadLatency INTEGER,CopyLatency INTEGER,CONSTRAINT fk_column_trecall FOREIGN KEY (subreqid) REFERENCES requests (subreqid) ON DELETE CASCADE)
PARTITION BY RANGE (timestamp) (PARTITION ' ||CreationDate || ' VALUES LESS THAN ( to_date('''||ts_var||''',''DD-MON-YYYY'')))';
execute immediate sql_txt;
commit;
sql_txt := 'CREATE TABLE DiskCopy(subreqid CHAR(36) NOT NULL PRIMARY KEY,timestamp DATE NOT NULL, OriginalPool VARCHAR2(255), TargetPool VARCHAR2(255),ReadLatency INTEGER,CopyLatency INTEGER, NumCopiesInPools INTEGER, DEST_HOST NUMBER, SRC_HOST VARCHAR2(255 BYTE))
PARTITION BY RANGE (timestamp) (PARTITION ' ||CreationDate || ' VALUES LESS THAN ( to_date('''||ts_var||''',''DD-MON-YYYY'')))';
execute immediate sql_txt;
commit;
sql_txt := 'CREATE TABLE DiskHits(timestamp DATE NOT NULL,subreqid CHAR(36) NOT NULL PRIMARY KEY, FileAge INTEGER, NumAccesses INTEGER, NumCopies INTEGER,CONSTRAINT fk_column_dhit FOREIGN KEY (subreqid) REFERENCES Requests (subreqid) ON DELETE CASCADE)
PARTITION BY RANGE (timestamp) (PARTITION ' ||CreationDate || ' VALUES LESS THAN ( to_date('''||ts_var||''',''DD-MON-YYYY'')))';
execute immediate sql_txt;
commit;
sql_txt := 'CREATE TABLE GCFiles(timestamp DATE NOT NULL,nsfileid NUMBER NOT NULL,FileSize NUMBER, FileAge NUMBER, LastAccessTime NUMBER, NbAccesses NUMBER, GcType VARCHAR2(255), SvcClass VARCHAR2(255))
PARTITION BY RANGE (timestamp) (PARTITION ' ||CreationDate || ' VALUES LESS THAN ( to_date('''||ts_var||''',''DD-MON-YYYY'')))';
execute immediate sql_txt;
commit;
sql_txt := 'CREATE TABLE Xrootd(timestamp DATE NOT NULL,message_type INTEGER, message_string VARCHAR2(100),message_int INTEGER, servername VARCHAR2(100))
PARTITION BY RANGE (timestamp) (PARTITION ' ||CreationDate || ' VALUES LESS THAN ( to_date('''||ts_var||''',''DD-MON-YYYY'')))';
execute immediate sql_txt;
commit;
sql_txt := 'CREATE TABLE Migration (subreqid CHAR(36) NOT NULL PRIMARY KEY, timestamp DATE NOT NULL, reqid CHAR(36) NOT NULL, nsfileid NUMBER NOT NULL, type VARCHAR2(255), svcclass VARCHAR2(255), username VARCHAR2(255), state VARCHAR2(255),filename VARCHAR2(2048), totallatency NUMBER, filesize NUMBER)
PARTITION BY RANGE (timestamp) (PARTITION ' ||CreationDate || ' VALUES LESS THAN ( to_date('''||ts_var||''',''DD-MON-YYYY'')))';
execute immediate sql_txt;
commit;
END;
/
CREATE INDEX i_req_timestamp ON Requests (timestamp) LOCAL;
CREATE INDEX i_req_reqid ON Requests (reqid);
CREATE INDEX i_mig_timestamp ON Migration (timestamp) LOCAL;
CREATE INDEX i_mig_reqid ON Migration (reqid);
CREATE INDEX i_dhit_timestamp ON DiskHits (timestamp) LOCAL;
CREATE INDEX i_dcopy_timestamp ON DiskCopy (timestamp) LOCAL;
CREATE INDEX i_trecall_timestamp ON TapeRecall (timestamp) LOCAL;
CREATE INDEX i_gcfiles_timestamp ON GCFiles (timestamp) LOCAL;
CREATE INDEX i_xrootd_timestamp ON Xrootd (timestamp) LOCAL;
CREATE INDEX i_idc_timestamp ON internalDiskCopy(timestamp) LOCAL;
CREATE INDEX i_errors_timestamp ON Errors(timestamp) LOCAL;
CREATE INDEX i_errors_facility ON Errors(facility);
CREATE INdex i_errors_msg_no ON Errors(msg_no);
CREATE INDEX i_tlat_timestamp ON TotalLatency(timestamp) LOCAL;
CREATE INDEX i_tlat_totallatency ON TotalLatency(totallatency);
--Materialized View - Files Requested After Deletion
CREATE MATERIALIZED VIEW req_del
REFRESH FORCE ON DEMAND START WITH sysdate NEXT sysdate + 10/1440
AS (select a.timestamp, round((a.timestamp - b.timestamp)*24,5) dif
from requests a , gcfiles b
where a.nsfileid = b.nsfileid
and a.state = 'TapeRecall'
and a.timestamp > b.timestamp
and a.timestamp - b.timestamp <= 1);
CREATE INDEX i_req_del ON req_del(dif);
--Materialized Views Used by Dashboard Feature
-- GC_monitor_view
CREATE MATERIALIZED VIEW gc_monitor
REFRESH COMPLETE ON DEMAND START WITH sysdate NEXT sysdate + 2/1440
from castor_dlf.dlf_messages mes, castor_dlf.dlf_num_param_values num, castor_dlf.dlf_str_param_values str
where mes.facility = 8
and mes.msg = 11
and mes.id = num.id and num.id = str.id
and num.name in ('FileSize','FileAge','LastAccessTime','NbAccesses')
and str.name in ('SvcClass','GcType')
and mes.timestamp >= maxtimestamp
and num.timestamp >= maxtimestamp
and str.timestamp >= maxtimestamp
and mes.timestamp < maxtimestamp + 5/1440
and num.timestamp < maxtimestamp + 5/1440
and str.timestamp < maxtimestamp + 5/1440
group by mes.timestamp,mes.nsfileid
COMMIT;
--Update maximum gc timestamp in ConfigSchema Table
SELECT max(timestamp) into new_timestamp FROM GCFiles WHERE timestamp > maxtimestamp;
if ((new_timestamp is NULL)or(new_timestamp - maxtimestamp < 5/1440)) then
begin
UPDATE ConfigSchema
SET gcmaxtime = gcmaxtime + 5/1440;
COMMIT;
end;
else
begin
UPDATE ConfigSchema
SET gcmaxtime = new_timestamp;
COMMIT;
end;
end if;
END;
-- (select to_number(value) NbAccesses from castor_dlf.dlf_num_param_values a, castor_dlf.dlf_messages b where b.facility=8 and b.msg_no=11 and a.id=b.id and a.name='NbAccesses' and
-- AND a.timestamp > now - 10/1440
-- and b.timestamp > now - 10/1440
-- and a.timestamp <= now - 5/1440
-- and b.timestamp <= now - 5/1440)
/
--Reqs Procedure - Extraxt Info for file Requests
--Global Requests Info
--
create or replace PROCEDURE reqs AS
maxtimestamp DATE;
new_maxtime date;
--define unique constraint exception
--Use exception handling to avoid proc failure
--Expected Unique Constraint Violation because of repeated message in DLF DB