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

[SQL/imaging] Adding SQL code for the new HRRT PET insertion scripts #6142

Merged
merged 1 commit into from
Jul 21, 2020
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
59 changes: 57 additions & 2 deletions SQL/0000-00-00-schema.sql
Original file line number Diff line number Diff line change
Expand Up @@ -419,6 +419,42 @@ CREATE TABLE `tarchive_files` (
CONSTRAINT `tarchive_files_TarchiveSeriesID_fk` FOREIGN KEY (`TarchiveSeriesID`) REFERENCES `tarchive_series` (`TarchiveSeriesID`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8;

-- ********************************
-- HRRT PET archive tables
-- ********************************
CREATE TABLE `hrrt_archive` (
`HrrtArchiveID` INT(11) NOT NULL AUTO_INCREMENT,
`SessionID` INT(10) unsigned DEFAULT NULL,
`EcatFileCount` INT(11) NOT NULL DEFAULT '0',
`NonEcatFileCount` INT(11) NOT NULL DEFAULT '0',
`DateAcquired` DATE DEFAULT NULL,
`DateArchived` DATETIME DEFAULT NULL,
`PatientName` VARCHAR(50) NOT NULL DEFAULT '',
PapillonMcGill marked this conversation as resolved.
Show resolved Hide resolved
`CenterName` VARCHAR(50) NOT NULL DEFAULT '',
PapillonMcGill marked this conversation as resolved.
Show resolved Hide resolved
`CreatingUser` VARCHAR(50) NOT NULL DEFAULT '',
`Blake2bArchive` VARCHAR(255) DEFAULT NULL,
`ArchiveLocation` VARCHAR(255) DEFAULT NULL,
PRIMARY KEY (`HrrtArchiveID`),
KEY `patNam` (`CenterName`(10),`PatientName`(30)),
KEY `FK_hrrt_archive_sessionID` (`SessionID`),
CONSTRAINT `FK_hrrt_archive_sessionID`
FOREIGN KEY (`SessionID`)
REFERENCES `session` (`ID`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8;

CREATE TABLE `hrrt_archive_files` (
`HrrtArchiveFileID` INT(11) NOT NULL AUTO_INCREMENT,
`HrrtArchiveID` INT(11) NOT NULL DEFAULT '0',
`Blake2bHash` VARCHAR(255) NOT NULL,
`FileName` VARCHAR(255) NOT NULL,
PRIMARY KEY (`HrrtArchiveFileID`),
KEY `HrrtArchiveID` (`HrrtArchiveID`),
CONSTRAINT `hrrt_archive_files_ibfk_1`
FOREIGN KEY (`HrrtArchiveID`)
REFERENCES `hrrt_archive` (`HrrtArchiveID`)
ON DELETE CASCADE
) ENGINE=InnoDB DEFAULT CHARSET=utf8;


-- ********************************
-- Imaging tables
Expand Down Expand Up @@ -522,6 +558,7 @@ CREATE TABLE `files` (
`ProcessProtocolID` int(11) unsigned,
`Caveat` tinyint(1) default NULL,
`TarchiveSource` int(11) default NULL,
`HrrtArchiveID` int(11) default NULL,
`ScannerID` int(10) unsigned default NULL,
`AcqOrderPerModality` int(11) default NULL,
PRIMARY KEY (`FileID`),
Expand All @@ -532,13 +569,15 @@ CREATE TABLE `files` (
KEY `AcquiIndex` (`AcquisitionProtocolID`,`SessionID`),
KEY `scannerid` (`ScannerID`),
KEY `tarchivesource` (`TarchiveSource`),
KEY `FK_files_HrrtArchiveID_1` (`HrrtArchiveID`),
CONSTRAINT `FK_files_2` FOREIGN KEY (`AcquisitionProtocolID`) REFERENCES `mri_scan_type` (`ID`),
CONSTRAINT `FK_files_1` FOREIGN KEY (`SessionID`) REFERENCES `session` (`ID`),
CONSTRAINT `FK_files_3` FOREIGN KEY (`SourceFileID`) REFERENCES `files` (`FileID`),
CONSTRAINT `FK_files_4` FOREIGN KEY (`ProcessProtocolID`) REFERENCES `mri_processing_protocol` (`ProcessProtocolID`),
CONSTRAINT `FK_files_FileTypes` FOREIGN KEY (`FileType`) REFERENCES `ImagingFileTypes`(`type`),
CONSTRAINT `FK_files_scannerID` FOREIGN KEY (`ScannerID`) REFERENCES `mri_scanner` (`ID`),
CONSTRAINT `FK_files_TarchiveID` FOREIGN KEY (`TarchiveSource`) REFERENCES `tarchive` (`TarchiveID`)
CONSTRAINT `FK_files_TarchiveID` FOREIGN KEY (`TarchiveSource`) REFERENCES `tarchive` (`TarchiveID`),
CONSTRAINT `FK_files_HrrtArchiveID` FOREIGN KEY (`HrrtArchiveID`) REFERENCES `hrrt_archive` (`HrrtArchiveID`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8;

CREATE TABLE `files_intermediary` (
Expand Down Expand Up @@ -662,6 +701,21 @@ CREATE TABLE `mri_upload` (
FOREIGN KEY (`TarchiveID`) REFERENCES `tarchive` (`TarchiveID`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8;

CREATE TABLE `mri_upload_rel` (
`UploadRelID` INT(10) UNSIGNED NOT NULL AUTO_INCREMENT,
`UploadID` INT(10) UNSIGNED NOT NULL,
`HrrtArchiveID` INT(11) DEFAULT NULL,
PRIMARY KEY (`UploadRelID`),
KEY `FK_mriuploadrel_UploadID` (`UploadID`),
KEY `FK_mriuploadrel_HrrtArchiveID` (`HrrtArchiveID`),
CONSTRAINT `FK_mriuploadrel_UploadID`
FOREIGN KEY (`UploadID`)
REFERENCES `mri_upload` (`UploadID`),
CONSTRAINT `FK_mriuploadrel_HrrtArchiveID`
FOREIGN KEY (`HrrtArchiveID`)
REFERENCES `hrrt_archive` (`HrrtArchiveID`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8;

CREATE TABLE `mri_protocol_checks_group` (
`MriProtocolChecksGroupID` INT(4) UNSIGNED NOT NULL AUTO_INCREMENT,
`Name` VARCHAR(255) NOT NULL UNIQUE,
Expand Down Expand Up @@ -944,7 +998,8 @@ INSERT INTO `notification_types` (Type,private,Description) VALUES
('tarchive validation',1,'Validation of the dicoms After uploading'),
('mri upload runner',1,'Validation of DICOMS before uploading'),
('mri upload processing class',1,'Validation and execution of DicomTar.pl and TarchiveLoader'),
('imaging non minc file insertion', 1, 'Insertion of a non-MINC file into the MRI tables (files/parameter_file)');
('imaging non minc file insertion', 1, 'Insertion of a non-MINC file into the MRI tables (files/parameter_file)'),
('hrrt pet new series', 0, 'New HRRT PET studies inserted into the database');

CREATE TABLE `notification_spool` (
`NotificationID` int(11) NOT NULL auto_increment,
Expand Down
Original file line number Diff line number Diff line change
@@ -0,0 +1,68 @@
-- Create the hrrt_archive and hrrt_archive_files tables
CREATE TABLE `hrrt_archive` (
`HrrtArchiveID` INT(11) NOT NULL AUTO_INCREMENT,
`SessionID` INT(10) unsigned DEFAULT NULL,
`EcatFileCount` INT(11) NOT NULL DEFAULT '0',
`NonEcatFileCount` INT(11) NOT NULL DEFAULT '0',
`DateAcquired` DATE DEFAULT NULL,
`DateArchived` DATETIME DEFAULT NULL,
`PatientName` VARCHAR(50) NOT NULL DEFAULT '',
`CenterName` VARCHAR(50) NOT NULL DEFAULT '',
`CreatingUser` VARCHAR(50) NOT NULL DEFAULT '',
`Blake2bArchive` VARCHAR(255) DEFAULT NULL,
`ArchiveLocation` VARCHAR(255) DEFAULT NULL,
PRIMARY KEY (`HrrtArchiveID`),
KEY `patNam` (`CenterName`(10),`PatientName`(30)),
KEY `FK_hrrt_archive_sessionID` (`SessionID`),
CONSTRAINT `FK_hrrt_archive_sessionID`
FOREIGN KEY (`SessionID`)
REFERENCES `session` (`ID`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8;


CREATE TABLE `hrrt_archive_files` (
`HrrtArchiveFileID` INT(11) NOT NULL AUTO_INCREMENT,
`HrrtArchiveID` INT(11) NOT NULL DEFAULT '0',
`Blake2bHash` VARCHAR(255) NOT NULL,
`FileName` VARCHAR(255) NOT NULL,
PRIMARY KEY (`HrrtArchiveFileID`),
KEY `HrrtArchiveID` (`HrrtArchiveID`),
CONSTRAINT `hrrt_archive_files_ibfk_1`
FOREIGN KEY (`HrrtArchiveID`)
REFERENCES `hrrt_archive` (`HrrtArchiveID`)
ON DELETE CASCADE
) ENGINE=InnoDB DEFAULT CHARSET=utf8;



-- Create the mri_upload_rel table
CREATE TABLE `mri_upload_rel` (
`UploadRelID` INT(10) UNSIGNED NOT NULL AUTO_INCREMENT,
`UploadID` INT(10) UNSIGNED NOT NULL,
`HrrtArchiveID` INT(11) DEFAULT NULL,
PRIMARY KEY (`UploadRelID`),
KEY `FK_mriuploadrel_UploadID` (`UploadID`),
KEY `FK_mriuploadrel_HrrtArchiveID` (`HrrtArchiveID`),
CONSTRAINT `FK_mriuploadrel_UploadID`
FOREIGN KEY (`UploadID`)
REFERENCES `mri_upload` (`UploadID`),
CONSTRAINT `FK_mriuploadrel_HrrtArchiveID`
FOREIGN KEY (`HrrtArchiveID`)
REFERENCES `hrrt_archive` (`HrrtArchiveID`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8;


-- Insert into notification type 'hrrt pet new series'
INSERT INTO notification_types SET
Type = 'hrrt pet new series',
private = 0,
Description = 'New HRRT PET studies inserted into the database';


-- Alter files table to add a HrrtArchiveID field that links HRRT MINC files
-- to hrrt_archive tables
ALTER TABLE files
ADD COLUMN `HrrtArchiveID` INT(11) DEFAULT NULL,
ADD KEY `FK_files_HrrtArchiveID_1` (`HrrtArchiveID`),
ADD CONSTRAINT `FK_files_HrrtArchiveID`
FOREIGN KEY (`HrrtArchiveID`) REFERENCES `hrrt_archive` (`HrrtArchiveID`);