Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Separate Facilities #18

Merged
merged 44 commits into from
Feb 3, 2025
Merged

Separate Facilities #18

merged 44 commits into from
Feb 3, 2025

Conversation

slominskir
Copy link
Member

Fixes #1
Separate RF Operations
Fixes #15

@slominskir slominskir merged commit 115ec62 into main Feb 3, 2025
4 checks passed
@slominskir slominskir deleted the separate-facilities branch February 3, 2025 14:07
@slominskir
Copy link
Member Author

slominskir commented Feb 3, 2025

Oracle DB Migration Notes:

Sequences

CREATE SEQUENCE JAM_OWNER.RF_AUTHORIZATION_ID
    START WITH 1
    NOCYCLE
    NOCACHE
    ORDER;

SELECT last_number
  FROM user_sequences
 WHERE sequence_name = 'AUTHORIZATION_ID';

DROP SEQUENCE AUTHORIZATION_ID;

CREATE SEQUENCE JAM_OWNER.BEAM_AUTHORIZATION_ID
    START WITH 7000
    NOCYCLE
    NOCACHE
    ORDER;

CREATE SEQUENCE JAM_OWNER.RF_SEGMENT_ID
    START WITH 1
    NOCYCLE
    NOCACHE
    ORDER;


SELECT last_number
  FROM user_sequences
 WHERE sequence_name = 'DESTINATION_ID';

DROP SEQUENCE DESTINATION_ID;

CREATE SEQUENCE JAM_OWNER.BEAM_DESTINATION_ID
    START WITH 1
    NOCYCLE
    NOCACHE
    ORDER;
CREATE SEQUENCE JAM_OWNER.RF_CONTROL_VERIFICATION_ID
    START WITH 1
    NOCYCLE
    NOCACHE
    ORDER;

SELECT last_number
  FROM user_sequences
 WHERE sequence_name = 'CONTROL_VERIFICATION_ID';

DROP SEQUENCE CONTROL_VERIFICATION_ID;

CREATE SEQUENCE JAM_OWNER.BEAM_CONTROL_VERIFICATION_ID
    START WITH 3000
    NOCYCLE
    NOCACHE
    ORDER;

CREATE SEQUENCE JAM_OWNER.RF_CONTROL_VERIFICATION_HISTORY_ID
    START WITH 1
    NOCYCLE
    NOCACHE
    ORDER;

SELECT last_number
  FROM user_sequences
 WHERE sequence_name = 'VERIFICATION_HISTORY_ID';

DROP SEQUENCE VERIFICATION_HISTORY_ID;

CREATE SEQUENCE JAM_OWNER.BEAM_CONTROL_VERIFICATION_HISTORY_ID
    START WITH 400
    NOCYCLE
    NOCACHE
    ORDER;

Tables

CREATE TABLE JAM_OWNER.FACILITY
(
    FACILITY_ID       INTEGER NOT NULL,
    NAME              VARCHAR2(64 CHAR) NOT NULL,
    PATH              VARCHAR2(32 CHAR) NOT NULL,
    RF_WORKGROUP_ID   INTEGER NOT NULL,
    BEAM_WORKGROUP_ID INTEGER NOT NULL,
    WEIGHT            INTEGER NOT NULL,
    CONSTRAINT FACILITY_PK PRIMARY KEY (FACILITY_ID),
    CONSTRAINT FACILITY_AK1 UNIQUE (NAME),
    CONSTRAINT FACILITY_FK1 FOREIGN KEY (RF_WORKGROUP_ID) REFERENCES JAM_OWNER.WORKGROUP (WORKGROUP_ID),
    CONSTRAINT FACILITY_FK2 FOREIGN KEY (BEAM_WORKGROUP_ID) REFERENCES JAM_OWNER.WORKGROUP (WORKGROUP_ID)
);

-- Must have some default data to link existing operations
insert into JAM_OWNER.FACILITY (FACILITY_ID, NAME, PATH, RF_WORKGROUP_ID, BEAM_WORKGROUP_ID, WEIGHT) values (1, 'CEBAF', '/cebaf', 12, 12, 1);
insert into JAM_OWNER.FACILITY (FACILITY_ID, NAME, PATH, RF_WORKGROUP_ID, BEAM_WORKGROUP_ID, WEIGHT) values (2, 'LERF', '/lerf', 12, 12, 2);
insert into JAM_OWNER.FACILITY (FACILITY_ID, NAME, PATH, RF_WORKGROUP_ID, BEAM_WORKGROUP_ID, WEIGHT) values (3, 'UITF', '/uitf', 12, 12, 3);
insert into JAM_OWNER.FACILITY (FACILITY_ID, NAME, PATH, RF_WORKGROUP_ID, BEAM_WORKGROUP_ID, WEIGHT) values (4, 'CMTF', '/cmtf', 12, 12, 4);
insert into JAM_OWNER.FACILITY (FACILITY_ID, NAME, PATH, RF_WORKGROUP_ID, BEAM_WORKGROUP_ID, WEIGHT) values (5, 'VTA', '/vta', 12, 12, 5);
commit;

CREATE TABLE JAM_OWNER.RF_SEGMENT
(
    RF_SEGMENT_ID INTEGER NOT NULL,
    FACILITY_ID   INTEGER NOT NULL,
    NAME          VARCHAR2(64 CHAR) NOT NULL,
    ACTIVE_YN     CHAR(1 BYTE) DEFAULT 'Y' NOT NULL,
    WEIGHT        INTEGER NOT NULL,
    CONSTRAINT RF_SEGMENT_PK PRIMARY KEY (RF_SEGMENT_ID),
    CONSTRAINT RF_SEGMENT_AK1 UNIQUE (RF_SEGMENT_ID, FACILITY_ID),
    CONSTRAINT RF_SEGMENT_FK1 FOREIGN KEY (FACILITY_ID) REFERENCES JAM_OWNER.FACILITY (FACILITY_ID),
    CONSTRAINT RF_SEGMENT_CK1 CHECK (ACTIVE_YN IN ('Y', 'N'))
);

CREATE TABLE JAM_OWNER.RF_AUTHORIZATION
(
    RF_AUTHORIZATION_ID INTEGER NOT NULL,
    FACILITY_ID         INTEGER NOT NULL,
    MODIFIED_DATE       DATE NOT NULL,
    MODIFIED_BY         VARCHAR2(64 CHAR) NOT NULL,
    AUTHORIZATION_DATE  DATE NOT NULL,
    AUTHORIZED_BY       VARCHAR(64 CHAR) NOT NULL,
    COMMENTS            VARCHAR2(2048 CHAR) NULL,
    CONSTRAINT RF_AUTHORIZATION_PK PRIMARY KEY (RF_AUTHORIZATION_ID),
    CONSTRAINT RF_AUTHORIZATION_AK1 UNIQUE (RF_AUTHORIZATION_ID, FACILITY_ID),
    CONSTRAINT RF_AUTHORIZATION_FK1 FOREIGN KEY (FACILITY_ID) REFERENCES JAM_OWNER.FACILITY (FACILITY_ID)
);

CREATE TABLE JAM_OWNER.RF_SEGMENT_AUTHORIZATION
(
    RF_SEGMENT_ID       INTEGER NOT NULL,
    RF_AUTHORIZATION_ID INTEGER NOT NULL,
    FACILITY_ID         INTEGER NOT NULL,
    RF_MODE             VARCHAR2(16) NOT NULL,
    COMMENTS            VARCHAR2(256) NULL,
    EXPIRATION_DATE     DATE NULL,
    CONSTRAINT RF_SEGMENT_AUTHORIZATION_PK PRIMARY KEY (RF_SEGMENT_ID,RF_AUTHORIZATION_ID),
    CONSTRAINT RF_SEGMENT_AUTHORIZATION_FK1 FOREIGN KEY (RF_SEGMENT_ID, FACILITY_ID) REFERENCES JAM_OWNER.RF_SEGMENT (RF_SEGMENT_ID, FACILITY_ID),
    CONSTRAINT RF_SEGMENT_AUTHORIZATION_FK2 FOREIGN KEY (RF_AUTHORIZATION_ID, FACILITY_ID) REFERENCES JAM_OWNER.RF_AUTHORIZATION (RF_AUTHORIZATION_ID, FACILITY_ID),
    CONSTRAINT RF_SEGMENT_AUTHORIZATION_CK1 CHECK (RF_MODE IN ('None', 'RF On'))
);

-- BEAM_DESTINATION table
alter table JAM_OWNER.BEAM_DESTINATION add FACILITY_ID INTEGER DEFAULT 1 NOT NULL;
alter table JAM_OWNER.BEAM_DESTINATION add CONSTRAINT BEAM_DESTINATION_FK1 FOREIGN KEY (FACILITY_ID) REFERENCES JAM_OWNER.FACILITY (FACILITY_ID);
update JAM_OWNER.BEAM_DESTINATION set FACILITY_ID = 2 where MACHINE = 'lerf';
update JAM_OWNER.BEAM_DESTINATION set FACILITY_ID = 3 where MACHINE = 'uitf';
alter table JAM_OWNER.BEAM_DESTINATION drop column MACHINE;
alter table JAM_OWNER.BEAM_DESTINATION add CONSTRAINT BEAM_DESTINATION_AK1 UNIQUE (BEAM_DESTINATION_ID, FACILITY_ID);

-- BEAM_AUTHORIZATION table
rename AUTHORIZATION to BEAM_AUTHORIZATION;
alter table JAM_OWNER.BEAM_AUTHORIZATION rename column AUTHORIZATION_ID to BEAM_AUTHORIZATION_ID;
alter table JAM_OWNER.BEAM_AUTHORIZATION add FACILITY_ID INTEGER DEFAULT 1 NOT NULL;
alter table JAM_OWNER.BEAM_AUTHORIZATION add CONSTRAINT BEAM_AUTHORIZATION_AK1 UNIQUE (BEAM_AUTHORIZATION_ID, FACILITY_ID);
alter table JAM_OWNER.BEAM_AUTHORIZATION add CONSTRAINT BEAM_AUTHORIZATION_FK1 FOREIGN KEY (FACILITY_ID) REFERENCES JAM_OWNER.FACILITY (FACILITY_ID);

-- BEAM_DESTINATION_AUTHORIZATION table
rename DESTINATION_AUTHORIZATION to BEAM_DESTINATION_AUTHORIZATION;
alter table JAM_OWNER.BEAM_DESTINATION_AUTHORIZATION rename column AUTHORIZATION_ID to BEAM_AUTHORIZATION_ID;
alter table JAM_OWNER.BEAM_DESTINATION_AUTHORIZATION add FACILITY_ID INTEGER DEFAULT 1 NOT NULL;
alter table JAM_OWNER.BEAM_DESTINATION_AUTHORIZATION add CONSTRAINT BEAM_DESTINATION_AUTHORIZATION_FK1 FOREIGN KEY (BEAM_DESTINATION_ID, FACILITY_ID) REFERENCES JAM_OWNER.BEAM_DESTINATION (BEAM_DESTINATION_ID, FACILITY_ID);
alter table JAM_OWNER.BEAM_DESTINATION_AUTHORIZATION add CONSTRAINT BEAM_DESTINATION_AUTHORIZATION_FK2 FOREIGN KEY (BEAM_AUTHORIZATION_ID, FACILITY_ID) REFERENCES JAM_OWNER.BEAM_AUTHORIZATION (BEAM_AUTHORIZATION_ID, FACILITY_ID);

-- VERIFICATION_STATUS table
rename VERIFICATION to VERIFICATION_STATUS;
alter table JAM_OWNER.VERIFICATION_STATUS rename column VERIFICATION_ID to VERIFICATION_STATUS_ID;

CREATE TABLE JAM_OWNER.RF_CONTROL_VERIFICATION
(
    RF_CONTROL_VERIFICATION_ID INTEGER NOT NULL,
    CREDITED_CONTROL_ID        INTEGER NULL,
    RF_SEGMENT_ID              INTEGER NOT NULL,
    VERIFICATION_STATUS_ID     INTEGER NOT NULL,
    VERIFICATION_DATE          DATE NULL,
    VERIFIED_BY                VARCHAR(64 CHAR) NULL,
    EXPIRATION_DATE            DATE NULL,
    COMMENTS                   VARCHAR2(2048 CHAR) NULL,
    MODIFIED_BY                VARCHAR2(64 CHAR) NOT NULL,
    MODIFIED_DATE              DATE NOT NULL,
    CONSTRAINT RF_CONTROL_VERIFICATION_PK PRIMARY KEY (RF_CONTROL_VERIFICATION_ID),
    CONSTRAINT RF_CONTROL_VERIFICATION_AK1 UNIQUE (CREDITED_CONTROL_ID,RF_SEGMENT_ID),
    CONSTRAINT RF_CONTROL_VERIFICATION_FK1 FOREIGN KEY (CREDITED_CONTROL_ID) REFERENCES JAM_OWNER.CREDITED_CONTROL (CREDITED_CONTROL_ID) ON DELETE CASCADE,
    CONSTRAINT RF_CONTROL_VERIFICATION_FK2 FOREIGN KEY (RF_SEGMENT_ID) REFERENCES JAM_OWNER.RF_SEGMENT (RF_SEGMENT_ID) ON DELETE CASCADE,
    CONSTRAINT RF_CONTROL_VERIFICATION_FK3 FOREIGN KEY (VERIFICATION_STATUS_ID) REFERENCES JAM_OWNER.VERIFICATION_STATUS (VERIFICATION_STATUS_ID) ON DELETE SET NULL
);

CREATE TABLE JAM_OWNER.RF_CONTROL_VERIFICATION_HISTORY
(
    RF_CONTROL_VERIFICATION_HISTORY_ID INTEGER NOT NULL,
    RF_CONTROL_VERIFICATION_ID         INTEGER NOT NULL,
    VERIFICATION_STATUS_ID             INTEGER NOT NULL,
    VERIFIED_BY                        VARCHAR2(64 CHAR) NULL,
    VERIFICATION_DATE                  DATE NOT NULL,
    EXPIRATION_DATE                    DATE NULL,
    COMMENTS                           VARCHAR2(2048 CHAR) NULL,
    MODIFIED_BY                        VARCHAR2(64 CHAR) NOT NULL,
    MODIFIED_DATE                      DATE NOT NULL,
    CONSTRAINT RF_CONTROL_VERIFICATION_HISTORY_PK PRIMARY KEY (RF_CONTROL_VERIFICATION_HISTORY_ID),
    CONSTRAINT RF_CONTROL_VERIFICATION_HISTORY_FK1 FOREIGN KEY (RF_CONTROL_VERIFICATION_ID) REFERENCES JAM_OWNER.RF_CONTROL_VERIFICATION (RF_CONTROL_VERIFICATION_ID) ON DELETE CASCADE,
    CONSTRAINT RF_CONTROL_VERIFICATION_HISTORY_FK3 FOREIGN KEY (VERIFICATION_STATUS_ID) REFERENCES JAM_OWNER.VERIFICATION_STATUS (VERIFICATION_STATUS_ID) ON DELETE SET NULL
);

CREATE TABLE JAM_OWNER.RF_CONTROL_VERIFICATION_COMPONENT
(
    RF_CONTROL_VERIFICATION_ID INTEGER NOT NULL ,
    COMPONENT_ID               INTEGER NOT NULL ,
    CONSTRAINT RF_CONTROL_VERIFICATION_COMPONENT_PK PRIMARY KEY (RF_CONTROL_VERIFICATION_ID, COMPONENT_ID),
    CONSTRAINT RF_CONTROL_VERIFICATION_COMPONENT_FK1 FOREIGN KEY (RF_CONTROL_VERIFICATION_ID) REFERENCES JAM_OWNER.RF_CONTROL_VERIFICATION (RF_CONTROL_VERIFICATION_ID) ON DELETE CASCADE
);

-- BEAM_CONTROL_VERIFICATION table
rename CONTROL_VERIFICATION to BEAM_CONTROL_VERIFICATION;
alter table JAM_OWNER.BEAM_CONTROL_VERIFICATION rename column CONTROL_VERIFICATION_ID to BEAM_CONTROL_VERIFICATION_ID;
alter table JAM_OWNER.BEAM_CONTROL_VERIFICATION rename column VERIFICATION_ID to VERIFICATION_STATUS_ID;

-- BEAM_CONTROL_VERIFICATION_HISTORY table
rename VERIFICATION_HISTORY to BEAM_CONTROL_VERIFICATION_HISTORY;
alter table JAM_OWNER.BEAM_CONTROL_VERIFICATION_HISTORY rename column VERIFICATION_HISTORY_ID to BEAM_CONTROL_VERIFICATION_HISTORY_ID;
alter table JAM_OWNER.BEAM_CONTROL_VERIFICATION_HISTORY rename column VERIFICATION_ID to VERIFICATION_STATUS_ID;
alter table JAM_OWNER.BEAM_CONTROL_VERIFICATION_HISTORY rename column CONTROL_VERIFICATION_ID to BEAM_CONTROL_VERIFICATION_ID;


-- BEAM_CONTROL_VERIFICATION_COMPONENT table
rename VERIFICATION_COMPONENT to BEAM_CONTROL_VERIFICATION_COMPONENT;
alter table JAM_OWNER.BEAM_CONTROL_VERIFICATION_COMPONENT rename column CONTROL_VERIFICATION_ID to BEAM_CONTROL_VERIFICATION_ID;

Views

CREATE OR REPLACE FORCE VIEW JAM_OWNER.FACILITY_CONTROL_VERIFICATION (FACILITY_ID, CREDITED_CONTROL_ID, VERIFICATION_STATUS_ID, EXPIRATION_DATE) AS
with segment_verification as (
   select facility_id, credited_control_id, rf_segment_id, verification_status_id, expiration_date from JAM_OWNER.RF_SEGMENT join RF_CONTROL_VERIFICATION using(RF_SEGMENT_ID) where active_yn = 'Y'
),
destination_verification as (
    select facility_id, credited_control_id, beam_destination_id, verification_status_id, expiration_date from JAM_OWNER.BEAM_DESTINATION join BEAM_CONTROL_VERIFICATION using(BEAM_DESTINATION_ID) where active_yn = 'Y'
),
operations_verification as (
    select facility_id, credited_control_id, verification_status_id, expiration_date from segment_verification
    union all
    select facility_id, credited_control_id, verification_status_id, expiration_date from destination_verification
)
    SELECT facility_id,
           credited_control_id,
           NVL(MAX(verification_status_id), 1) AS VERIFICATION_STATUS_ID,
           MIN(expiration_date) AS EXPIRATION_DATE
FROM JAM_OWNER.FACILITY join operations_verification using (facility_id) group by facility_id, credited_control_id;

CREATE OR REPLACE FORCE VIEW JAM_OWNER.RF_SEGMENT_VERIFICATION (RF_SEGMENT_ID, VERIFICATION_STATUS_ID, EXPIRATION_DATE) AS
SELECT a.rf_segment_id,
       NVL((SELECT MAX(VERIFICATION_STATUS_ID) FROM JAM_OWNER.RF_CONTROL_VERIFICATION b WHERE a.rf_segment_id = b.rf_segment_id), 1) AS VERIFICATION_STATUS_ID,
       (SELECT MIN(EXPIRATION_DATE) FROM JAM_OWNER.RF_CONTROL_VERIFICATION b WHERE a.rf_segment_id = b.rf_segment_id) as EXPIRATION_DATE
FROM JAM_OWNER.RF_SEGMENT a;

CREATE OR REPLACE FORCE VIEW JAM_OWNER.BEAM_DESTINATION_VERIFICATION (BEAM_DESTINATION_ID, VERIFICATION_STATUS_ID, EXPIRATION_DATE) AS
SELECT a.beam_destination_id,
       NVL((SELECT MAX(VERIFICATION_STATUS_ID) FROM JAM_OWNER.BEAM_CONTROL_VERIFICATION b WHERE a.beam_destination_id = b.beam_destination_id), 1) AS VERIFICATION_STATUS_ID,
       (SELECT MIN(EXPIRATION_DATE) FROM JAM_OWNER.BEAM_CONTROL_VERIFICATION b WHERE a.beam_destination_id = b.beam_destination_id) as EXPIRATION_DATE
FROM JAM_OWNER.BEAM_DESTINATION a;

Migrate Operations Data

update JAM_OWNER.BEAM_DESTINATION set ACTIVE_YN = 'N' where NAME like 'LERF%' OR NAME like 'UITF%';
update JAM_OWNER.BEAM_DESTINATION set ACTIVE_YN = 'N' where NAME like '%Operations';

-- Populate RF Segments
insert into JAM_OWNER.rf_segment (RF_SEGMENT_ID, NAME, FACILITY_ID, ACTIVE_YN, WEIGHT) values(JAM_OWNER.rf_segment_id.nextval, 'Injector', 1, 'Y', 1);
insert into JAM_OWNER.rf_segment (RF_SEGMENT_ID, NAME, FACILITY_ID, ACTIVE_YN, WEIGHT) values(JAM_OWNER.rf_segment_id.nextval, 'North Linac', 1, 'Y', 2);
insert into JAM_OWNER.rf_segment (RF_SEGMENT_ID, NAME, FACILITY_ID, ACTIVE_YN, WEIGHT) values(JAM_OWNER.rf_segment_id.nextval, 'South Linac', 1, 'Y', 3);
insert into JAM_OWNER.rf_segment (RF_SEGMENT_ID, NAME, FACILITY_ID, ACTIVE_YN, WEIGHT) values(JAM_OWNER.rf_segment_id.nextval, 'Entire Facility', 2, 'Y', 4);
insert into JAM_OWNER.rf_segment (RF_SEGMENT_ID, NAME, FACILITY_ID, ACTIVE_YN, WEIGHT) values(JAM_OWNER.rf_segment_id.nextval, 'Entire Facility', 3, 'Y', 5);
insert into JAM_OWNER.rf_segment (RF_SEGMENT_ID, NAME, FACILITY_ID, ACTIVE_YN, WEIGHT) values(JAM_OWNER.rf_segment_id.nextval, 'Entire Facility', 4, 'Y', 6);
insert into JAM_OWNER.rf_segment (RF_SEGMENT_ID, NAME, FACILITY_ID, ACTIVE_YN, WEIGHT) values(JAM_OWNER.rf_segment_id.nextval, 'Entire Facility', 5, 'Y', 7);

-- New Destinations
insert into JAM_OWNER.beam_destination (BEAM_DESTINATION_ID, NAME, FACILITY_ID, CURRENT_LIMIT_UNITS, ACTIVE_YN, WEIGHT) values(100, '0G Tune/Moeller Dump', 2, 'uA', 'Y', 1000);
insert into JAM_OWNER.beam_destination (BEAM_DESTINATION_ID, NAME, FACILITY_ID, CURRENT_LIMIT_UNITS, ACTIVE_YN, WEIGHT) values(101, '2G 100MeV SA Dump (IDC2G00)', 2, 'mA', 'Y', 1001);
insert into JAM_OWNER.beam_destination (BEAM_DESTINATION_ID, NAME, FACILITY_ID, CURRENT_LIMIT_UNITS, ACTIVE_YN, WEIGHT) values(102, '1G Dump (IDC1G03)', 2, 'mA', 'Y', 1002);
insert into JAM_OWNER.beam_destination (BEAM_DESTINATION_ID, NAME, FACILITY_ID, CURRENT_LIMIT_UNITS, ACTIVE_YN, WEIGHT) values(103, '1X Dump', 2, 'mA', 'Y', 1003);
insert into JAM_OWNER.beam_destination (BEAM_DESTINATION_ID, NAME, FACILITY_ID, CURRENT_LIMIT_UNITS, ACTIVE_YN, WEIGHT) values(200, 'KeV Dumps', 3, 'uA', 'Y', 2000);
insert into JAM_OWNER.beam_destination (BEAM_DESTINATION_ID, NAME, FACILITY_ID, CURRENT_LIMIT_UNITS, ACTIVE_YN, WEIGHT) values(201, 'MeV Dumps', 3, 'uA', 'Y', 2001);

Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment
Labels
None yet
Projects
None yet
Development

Successfully merging this pull request may close these issues.

Differentiate between RF Ops vs Beam Ops Separate Permissions for each machine
1 participant