Skip to content

Commit

Permalink
Merge pull request #4467 from ridz1208/2019_04_18_no_pub_in_schema
Browse files Browse the repository at this point in the history
Add publication module SQL to the schema files
  • Loading branch information
ridz1208 authored Apr 26, 2019
2 parents 5651af9 + 4c28283 commit b0a21ae
Show file tree
Hide file tree
Showing 5 changed files with 140 additions and 6 deletions.
121 changes: 119 additions & 2 deletions SQL/0000-00-00-schema.sql
Original file line number Diff line number Diff line change
Expand Up @@ -993,10 +993,13 @@ INSERT INTO notification_modules (module_name, operation_type, as_admin, templat
('document_repository', 'new_category', 'N', 'notifier_document_repository_new_category.tpl', 'Document Repository: New Category'),
('document_repository', 'upload', 'N', 'notifier_document_repository_upload.tpl', 'Document Repository: New Document Uploaded'),
('document_repository', 'delete', 'N', 'notifier_document_repository_delete.tpl', 'Document Repository: Document Deleted'),
('document_repository', 'edit', 'N', 'notifier_document_repository_edit.tpl', 'Document Repository: Document Edited');
('document_repository', 'edit', 'N', 'notifier_document_repository_edit.tpl', 'Document Repository: Document Edited'),
('publication', 'submission', 'N', 'notifier_publication_submission.tpl', 'Publication: Submission Received'),
('publication', 'review', 'N', 'notifier_publication_review.tpl', 'Publication: Proposal has been reviewed'),
('publication', 'edit', 'N', 'notifier_publication_edit.tpl', 'Publication: Proposal has been edited');

-- enable doc repo basic text emails
INSERT INTO notification_modules_services_rel SELECT nm.id, ns.id FROM notification_modules nm JOIN notification_services ns WHERE nm.module_name='document_repository' AND ns.service='email_text';
INSERT INTO notification_modules_services_rel SELECT nm.id, ns.id FROM notification_modules nm JOIN notification_services ns WHERE nm.module_name='publication' AND ns.service='email_text';

-- Transfer Document repository notifications to new system
INSERT INTO users_notifications_rel SELECT u.ID, nm.id, ns.id FROM users u JOIN notification_modules nm JOIN notification_services ns WHERE nm.module_name='document_repository' AND ns.service='email_text' AND u.Doc_Repo_Notifications='Y';
Expand Down Expand Up @@ -2045,3 +2048,117 @@ CREATE TABLE `candidate_consent_history` (
`EntryStaff` varchar(255) DEFAULT NULL,
CONSTRAINT `PK_candidate_consent_history` PRIMARY KEY (`CandidateConsentHistoryID`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8;

-- Publication Status
CREATE TABLE `publication_status` (
`PublicationStatusID` int(2) unsigned NOT NULL AUTO_INCREMENT,
`Label` varchar(255) NOT NULL,
CONSTRAINT `PK_publication_status` PRIMARY KEY(`PublicationStatusID`),
CONSTRAINT `UK_publication_status_Label` UNIQUE (`Label`)
) ENGINE=InnoDB DEFAULT CHARSET='utf8';
INSERT INTO publication_status (`Label`) VALUES ('Pending');
INSERT INTO publication_status (`Label`) VALUES ('Approved');
INSERT INTO publication_status (`Label`) VALUES ('Rejected');

CREATE TABLE `publication_collaborator` (
`PublicationCollaboratorID` int(10) unsigned NOT NULL AUTO_INCREMENT,
`Name` varchar(255) NOT NULL,
`Email` varchar(255),
CONSTRAINT `PK_publication_collaborator` PRIMARY KEY(`PublicationCollaboratorID`),
CONSTRAINT `UK_publication_collaborator_Email` UNIQUE (`Email`)
) ENGINE=InnoDB DEFAULT CHARSET='utf8';

-- Main table
CREATE TABLE `publication` (
`PublicationID` int(10) unsigned NOT NULL AUTO_INCREMENT,
`PublicationStatusID` int(2) unsigned NOT NULL default 1,
`LeadInvestigatorID` int(10) unsigned NOT NULL,
`UserID` int(10) unsigned NOT NULL,
`RatedBy` int(10) unsigned,
`DateProposed` date NOT NULL,
`DateRated` date default NULL,
`Title` varchar(255) NOT NULL,
`RejectedReason` varchar(255) default NULL,
`Description` text NOT NULL,
CONSTRAINT `PK_publication` PRIMARY KEY(`PublicationID`),
CONSTRAINT `FK_publication_UserID` FOREIGN KEY(`UserID`) REFERENCES `users` (`ID`),
CONSTRAINT `FK_publication_RatedBy` FOREIGN KEY(`RatedBy`) REFERENCES `users` (`ID`),
CONSTRAINT `FK_publication_PublicationStatusID` FOREIGN KEY(`PublicationStatusID`) REFERENCES `publication_status` (`PublicationStatusID`),
CONSTRAINT `FK_publication_LeadInvestigatorID` FOREIGN KEY(`LeadInvestigatorID`) REFERENCES `publication_collaborator` (`PublicationCollaboratorID`),
CONSTRAINT `UK_publication_Title` UNIQUE (`Title`)
) ENGINE=InnoDB DEFAULT CHARSET='utf8';

-- Separate table for Keywords
CREATE TABLE `publication_keyword` (
`PublicationKeywordID` int(10) unsigned NOT NULL AUTO_INCREMENT,
`Label` varchar(255) NOT NULL,
CONSTRAINT `PK_publication_keyword` PRIMARY KEY(`PublicationKeywordID`),
CONSTRAINT `UK_publication_Label` UNIQUE (`Label`)
) ENGINE=InnoDB DEFAULT CHARSET='utf8';

-- Publication - Keyword relational table
CREATE TABLE `publication_keyword_rel` (
`PublicationID` int(10) unsigned NOT NULL,
`PublicationKeywordID` int(10) unsigned NOT NULL,
CONSTRAINT `PK_publication_keyword_rel` PRIMARY KEY(PublicationID, PublicationKeywordID),
CONSTRAINT `FK_publication_keyword_PublicationID` FOREIGN KEY(`PublicationID`) REFERENCES `publication` (`PublicationID`),
CONSTRAINT `FK_publication_keyword_PublicationKeywordID` FOREIGN KEY(`PublicationKeywordID`) REFERENCES `publication_keyword` (`PublicationKeywordID`)
) ENGINE=InnoDB DEFAULT CHARSET='utf8';

CREATE TABLE `publication_collaborator_rel` (
`PublicationID` int(10) unsigned NOT NULL,
`PublicationCollaboratorID` int(10) unsigned NOT NULL,
CONSTRAINT `PK_publication_collaborator_rel` PRIMARY KEY(PublicationID, PublicationCollaboratorID),
CONSTRAINT `FK_publication_collaborator_rel_PublicationID` FOREIGN KEY(`PublicationID`) REFERENCES `publication` (`PublicationID`),
CONSTRAINT `FK_publication_collaborator_rel_PublicationCollaboratorID` FOREIGN KEY(`PublicationCollaboratorID`) REFERENCES `publication_collaborator` (`PublicationCollaboratorID`)
) ENGINE=InnoDB DEFAULT CHARSET='utf8';

-- Publication - Variable of Interest relational table
CREATE TABLE `publication_parameter_type_rel` (
`PublicationID` int(10) unsigned NOT NULL,
`ParameterTypeID` int(10) unsigned NOT NULL,
CONSTRAINT `PK_publication_parameter_type_rel` PRIMARY KEY (PublicationID, ParameterTypeID),
CONSTRAINT `FK_publication_parameter_type_rel_PublicationID` FOREIGN KEY (`PublicationID`) REFERENCES `publication` (`PublicationID`),
CONSTRAINT `FK_publication_parameter_type_rel_ParameterTypeID` FOREIGN KEY (`ParameterTypeID`) REFERENCES `parameter_type` (`ParameterTypeID`)
) ENGINE=InnoDB DEFAULT CHARSET='utf8';

CREATE TABLE `publication_test_names_rel` (
`PublicationID` int(10) unsigned NOT NULL,
`TestNameID` int(10) unsigned NOT NULL,
CONSTRAINT `PK_publication_test_names_rel` PRIMARY KEY(`PublicationID`, `TestNameID`),
CONSTRAINT `FK_publication_test_names_rel_PublicationID` FOREIGN KEY (`PublicationID`) REFERENCES `publication` (`PublicationID`),
CONSTRAINT `FK_publication_test_names_rel_TestNameID` FOREIGN KEY (`TestNameID`) REFERENCES `test_names` (`ID`)
) ENGINE=InnoDB DEFAULT CHARSET='utf8';

-- Publication Uploads
CREATE TABLE `publication_upload_type` (
`PublicationUploadTypeID` int(2) unsigned NOT NULL AUTO_INCREMENT,
`Label` varchar(255) NOT NULL,
CONSTRAINT `PK_publication_upload_type` PRIMARY KEY (`PublicationUploadTypeID`),
CONSTRAINT `UK_publication_Label` UNIQUE (`Label`)
) ENGINE=InnoDB DEFAULT CHARSET='utf8';

INSERT INTO publication_upload_type (`Label`) VALUES ('Paper');
INSERT INTO publication_upload_type (`Label`) VALUES ('Poster');
INSERT INTO publication_upload_type (`Label`) VALUES ('Presentation');
INSERT INTO publication_upload_type (`Label`) VALUES ('Other');

CREATE TABLE `publication_upload` (
`PublicationUploadID` int(10) unsigned NOT NULL AUTO_INCREMENT,
`PublicationID` int(10) unsigned NOT NULL,
`PublicationUploadTypeID` int(2) unsigned NOT NULL,
`Filename` varchar(255) NOT NULL,
`Version` varchar(255),
`Citation` text,
CONSTRAINT `PK_publication_upload` PRIMARY KEY (`PublicationUploadID`),
CONSTRAINT `UK_publication_upload_Filename` UNIQUE (Filename),
CONSTRAINT `FK_publication_upload_PublicationID` FOREIGN KEY (`PublicationID`) REFERENCES `publication` (`PublicationID`),
CONSTRAINT `FK_publication_upload_PublicationUploadTypeID` FOREIGN KEY (`PublicationUploadTypeID`) REFERENCES `publication_upload_type` (`PublicationUploadTypeID`)
) ENGINE=InnoDB DEFAULT CHARSET='utf8';

CREATE TABLE `publication_users_edit_perm_rel` (
`PublicationID` int(10) unsigned NOT NULL AUTO_INCREMENT,
`UserID` int(10) unsigned NOT NULL,
CONSTRAINT `FK_publication_users_edit_perm_rel_PublicationID` FOREIGN KEY (`PublicationID`) REFERENCES `publication` (`PublicationID`),
CONSTRAINT `FK_publication_users_edit_perm_rel_UserID` FOREIGN KEY (`UserID`) REFERENCES `users` (`ID`)
) ENGINE=InnoDB DEFAULT CHARSET='utf8';
6 changes: 5 additions & 1 deletion SQL/0000-00-01-Permission.sql
Original file line number Diff line number Diff line change
Expand Up @@ -111,7 +111,10 @@ INSERT INTO `permissions` VALUES
(47,'imaging_browser_phantom_allsites', 'Can access only phantom data from all sites in Imaging Browser', 2),
(48,'imaging_browser_phantom_ownsite', 'Can access only phantom data from own site in Imaging Browser', 2),
(49,'data_release_upload', 'Data Release: Upload file', 2),
(50,'data_release_edit_file_access', 'Data Release: Grant other users view-file permissions', 2);
(50,'data_release_edit_file_access', 'Data Release: Grant other users view-file permissions', 2),
(51,'publication_view', 'Publication - Access to module', 2),
(52,'publication_propose', 'Publication - Propose a project', 2),
(53,'publication_approve', 'Publication - Approve or reject proposed publication projects', 2);


INSERT INTO `user_perm_rel` (userID, permID)
Expand All @@ -133,3 +136,4 @@ CREATE TABLE `notification_modules_perm_rel` (
-- populate notification perm table
INSERT INTO notification_modules_perm_rel SELECT nm.id, p.permID FROM notification_modules nm JOIN permissions p WHERE nm.module_name='media' AND (p.code='media_write' OR p.code='media_read');
INSERT INTO notification_modules_perm_rel SELECT nm.id, p.permID FROM notification_modules nm JOIN permissions p WHERE nm.module_name='document_repository' AND (p.code='document_repository_view' OR p.code='document_repository_delete');
INSERT INTO notification_modules_perm_rel SELECT nm.id, p.permID FROM notification_modules nm JOIN permissions p WHERE nm.module_name='publication' AND (p.code='publication_view' OR p.code='publication_propose' OR p.code='publication_approve');
9 changes: 8 additions & 1 deletion SQL/0000-00-02-Menus.sql
Original file line number Diff line number Diff line change
Expand Up @@ -66,7 +66,8 @@ INSERT INTO LorisMenu (Label, Link, Parent, OrderNumber) VALUES

INSERT INTO LorisMenu (Label, Link, Parent, OrderNumber) VALUES
('Statistics', 'statistics/', (SELECT ID FROM LorisMenu as L WHERE Label='Reports'), 1),
('Data Query Tool', 'dataquery/', (SELECT ID FROM LorisMenu as L WHERE Label='Reports'), 2);
('Data Query Tool', 'dataquery/', (SELECT ID FROM LorisMenu as L WHERE Label='Reports'), 2),
('Publications', 'publication/', (SELECT ID FROM LorisMenu as L WHERE Label='Reports'), 3);


INSERT INTO LorisMenu (Label, Link, Parent, OrderNumber) VALUES
Expand Down Expand Up @@ -227,3 +228,9 @@ INSERT INTO LorisMenuPermissions (MenuID, PermID)
SELECT m.ID, p.PermID FROM permissions p CROSS JOIN LorisMenu m WHERE p.code='media_write' AND m.Label='Media';


INSERT INTO LorisMenuPermissions (MenuID, PermID)
SELECT m.ID, p.PermID FROM permissions p CROSS JOIN LorisMenu m WHERE p.code='publication_view' AND m.Label='Publications';
INSERT INTO LorisMenuPermissions (MenuID, PermID)
SELECT m.ID, p.PermID FROM permissions p CROSS JOIN LorisMenu m WHERE p.code='publication_propose' AND m.Label='Publications';
INSERT INTO LorisMenuPermissions (MenuID, PermID)
SELECT m.ID, p.PermID FROM permissions p CROSS JOIN LorisMenu m WHERE p.code='publication_approve' AND m.Label='Publications';
8 changes: 7 additions & 1 deletion SQL/0000-00-03-ConfigTables.sql
Original file line number Diff line number Diff line change
Expand Up @@ -83,7 +83,8 @@ INSERT INTO ConfigSettings (Name, Description, Visible, AllowMultiple, DataType,
INSERT INTO ConfigSettings (Name, Description, Visible, AllowMultiple, DataType, Parent, Label, OrderNumber) SELECT 'MRIUploadIncomingPath', 'Path to the upload directory for incoming MRI studies', 1, 0, 'text', ID, 'MRI Incoming Directory', 7 FROM ConfigSettings WHERE Name="paths";
INSERT INTO ConfigSettings (Name, Description, Visible, AllowMultiple, DataType, Parent, Label, OrderNumber) SELECT 'GenomicDataPath', 'Path to Genomic data files', 1, 0, 'text', ID, 'Genomic Data Path', 8 FROM ConfigSettings WHERE Name="paths";
INSERT INTO ConfigSettings (Name, Description, Visible, AllowMultiple, DataType, Parent, Label, OrderNumber) SELECT 'mediaPath', 'Path to uploaded media files', 1, 0, 'text', ID, 'Media', 9 FROM ConfigSettings WHERE Name="paths";

INSERT INTO ConfigSettings (Name, Description, Visible, AllowMultiple, DataType, Parent, Label, OrderNumber) SELECT 'publication_uploads', 'Path to uploaded publications', 1, 0, 'text', ID, 'Publications', 10 FROM ConfigSettings WHERE Name="paths";
INSERT INTO ConfigSettings (Name, Description, Visible, AllowMultiple, DataType, Parent, Label, OrderNumber) SELECT 'publication_deletions', 'Path to deleted publications', 1, 0, 'text', ID, 'Deleted Publications', 11 FROM ConfigSettings WHERE Name="paths";

INSERT INTO ConfigSettings (Name, Description, Visible, AllowMultiple, Label, OrderNumber) VALUES ('gui', 'Settings related to the overall display of LORIS', 1, 0, 'GUI', 3);
INSERT INTO ConfigSettings (Name, Description, Visible, AllowMultiple, DataType, Parent, Label, OrderNumber) SELECT 'css', 'CSS file used for rendering (default main.css)', 1, 0, 'text', ID, 'CSS file', 1 FROM ConfigSettings WHERE Name="gui";
Expand Down Expand Up @@ -156,6 +157,7 @@ INSERT INTO ConfigSettings (Name, Description, Visible, AllowMultiple, DataType,
INSERT INTO ConfigSettings (Name, Description, Visible, AllowMultiple, DataType, Parent, Label, OrderNumber) SELECT 'compute_snr_modalities', 'Modalities for which the SNR should be computed when running the insertion MRI scripts', 1, 1, 'scan_type', ID, 'Modalities on which SNR should be calculated', 21 FROM ConfigSettings WHERE Name="imaging_pipeline";
INSERT INTO ConfigSettings (Name, Description, Visible, AllowMultiple, DataType, Parent, Label, OrderNumber) SELECT 'reference_scan_type_for_defacing', 'Scan type to use as a reference for registration when defacing anatomical images (typically a T1W image)', 1, 0, 'scan_type', ID, 'Scan type to use as a reference for defacing (typically a T1W image)', 22 FROM ConfigSettings WHERE Name="imaging_pipeline";
INSERT INTO ConfigSettings (Name, Description, Visible, AllowMultiple, DataType, Parent, Label, OrderNumber) SELECT 'modalities_to_deface', 'Modalities for which defacing should be run and defaced image inserted in the database', 1, 1, 'scan_type', ID, 'Modalities on which to run the defacing pipeline', 23 FROM ConfigSettings WHERE Name="imaging_pipeline";

--
-- Filling Config table with default values
--
Expand Down Expand Up @@ -196,6 +198,8 @@ INSERT INTO Config (ConfigID, Value) SELECT ID, "/data/%PROJECTNAME%/bin/mri/" F
INSERT INTO Config (ConfigID, Value) SELECT ID, "/data/incoming/" FROM ConfigSettings WHERE Name="MRIUploadIncomingPath";
INSERT INTO Config (ConfigID, Value) SELECT ID, "/PATH/TO/Genomic-Data/" FROM ConfigSettings WHERE Name="GenomicDataPath";
INSERT INTO Config (ConfigID, Value) SELECT ID, "/data/uploads/" FROM ConfigSettings WHERE Name="mediaPath";
INSERT INTO Config (ConfigID, Value) SELECT ID, "/data/publication_uploads/" FROM ConfigSettings WHERE Name="publication_uploads";
INSERT INTO Config (ConfigID, Value) SELECT ID, "/data/publication_uploads/to_be_deleted/" FROM ConfigSettings WHERE Name="publication_deletions";


INSERT INTO Config (ConfigID, Value) SELECT ID, "main.css" FROM ConfigSettings WHERE Name="css";
Expand Down Expand Up @@ -261,3 +265,5 @@ INSERT INTO Config (ConfigID, Value) SELECT ID, 'flair' FROM ConfigSettings WHER
INSERT INTO Config (ConfigID, Value) SELECT ID, 't1' FROM ConfigSettings WHERE Name="modalities_to_deface";
INSERT INTO Config (ConfigID, Value) SELECT ID, 't2' FROM ConfigSettings WHERE Name="modalities_to_deface";
INSERT INTO Config (ConfigID, Value) SELECT ID, 'pd' FROM ConfigSettings WHERE Name="modalities_to_deface";


2 changes: 1 addition & 1 deletion SQL/Archive/20.3/2018-05-28_publication_schema.sql
Original file line number Diff line number Diff line change
Expand Up @@ -77,7 +77,7 @@ CREATE TABLE `publication_test_names_rel` (
CONSTRAINT `PK_publication_test_names_rel` PRIMARY KEY(`PublicationID`, `TestNameID`),
CONSTRAINT `FK_publication_test_names_rel_PublicationID` FOREIGN KEY (`PublicationID`) REFERENCES `publication` (`PublicationID`),
CONSTRAINT `FK_publication_test_names_rel_TestNameID` FOREIGN KEY (`TestNameID`) REFERENCES `test_names` (`ID`)
) ENGINE=InnoDB DEFAULT CHARSET='utf8mb4';
) ENGINE=InnoDB DEFAULT CHARSET='utf8';

-- Publication Uploads
CREATE TABLE `publication_upload_type` (
Expand Down

0 comments on commit b0a21ae

Please # to comment.