Skip to content

Commit 36db516

Browse files
authored
Refresh schema files and fix minor bug in grants file (#288)
* Use 'if not exists' when creating role * Refresh schema files
1 parent 7344af7 commit 36db516

File tree

4 files changed

+170
-10
lines changed

4 files changed

+170
-10
lines changed

grants/ispyb_expeye.sql

Lines changed: 1 addition & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -8,7 +8,7 @@ CREATE ROLE IF NOT EXISTS ispyb_expeye_core_role;
88

99
GRANT ispyb_propagation TO ispyb_expeye_core_role;
1010

11-
CREATE ROLE ispyb_expeye_acquisition_role;
11+
CREATE ROLE IF NOT EXISTS ispyb_expeye_acquisition_role;
1212

1313
GRANT SELECT, INSERT, UPDATE, DELETE ON Proposal TO ispyb_expeye_acquisition_role;
1414
GRANT SELECT, INSERT, UPDATE, DELETE ON BLSession TO ispyb_expeye_acquisition_role;

schemas/ispyb/lookups.sql

Lines changed: 9 additions & 2 deletions
Original file line numberDiff line numberDiff line change
@@ -287,7 +287,13 @@ INSERT INTO `SchemaStatus` (`schemaStatusId`, `scriptName`, `schemaStatus`, `rec
287287
(315,'2025_05_01_BLSamplePosition.sql','DONE','2025-05-09 15:21:06'),
288288
(316,'2025_05_01_XrayCentringResult_fk_blSampleId.sql','DONE','2025-05-09 15:21:06'),
289289
(317,'2025_05_02_BLSamplePosition_rename_column.sql','DONE','2025-05-09 15:21:06'),
290-
(318,'2025_05_12_AdminVar_bump_version.sql','DONE','2025-05-09 15:21:06');
290+
(318,'2025_05_12_AdminVar_bump_version.sql','DONE','2025-05-09 15:21:06'),
291+
(319,'2025_05_14_BLSamplePosition_recordTimeStamp_default.sql','DONE','2025-06-27 16:04:05'),
292+
(320,'2025_05_23_Ligand_and_junction_tables.sql','DONE','2025-06-27 16:04:05'),
293+
(321,'2025_05_28_BLSession_icatId.sql','DONE','2025-06-27 16:04:05'),
294+
(322,'2025_06_02_DewarRegistry_type.sql','DONE','2025-06-27 16:04:05'),
295+
(323,'2025_06_26_ContainerType_cryoem_puck.sql','DONE','2025-06-27 16:04:05'),
296+
(324,'2025_06_27_Tomogram_pixelLocation.sql','DONE','2025-06-27 16:04:05');
291297
/*!40000 ALTER TABLE `SchemaStatus` ENABLE KEYS */;
292298

293299
/*!40000 ALTER TABLE `ComponentType` DISABLE KEYS */;
@@ -358,7 +364,8 @@ INSERT INTO `ContainerType` (`containerTypeId`, `name`, `proposalType`, `active`
358364
(34,'I22_Grid_81','saxs',1,81,9,1,1,1,1,0,0,-1),
359365
(35,'I22_Capillary_Rack_25','saxs',1,25,25,1,1,1,1,0,0,-1),
360366
(36,'VMXm-Cartridge','mx',1,5,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL),
361-
(37,'VMXm-GridBox','mx',1,4,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL);
367+
(37,'VMXm-GridBox','mx',1,4,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL),
368+
(38,'Cryo-EM Puck','mx',1,12,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL);
362369
/*!40000 ALTER TABLE `ContainerType` ENABLE KEYS */;
363370

364371
/*!40000 ALTER TABLE `ExperimentType` DISABLE KEYS */;

schemas/ispyb/routines.sql

Lines changed: 113 additions & 5 deletions
Original file line numberDiff line numberDiff line change
@@ -4190,25 +4190,27 @@ BEGIN
41904190
SELECT
41914191
d.dewarId "id", d.shippingId "shippingId", d.code "name", d.comments "comments", d.storageLocation "storageLocation",
41924192
d.dewarStatus "status", d.isStorageDewar "isStorageDewar", d.barCode "barCode", d.firstExperimentId "firstSessionId",
4193-
d.type "type", d.facilityCode "facilityCode", d.weight "weight", d.deliveryAgent_barcode "deliveryAgentBarcode"
4193+
dr.type "type", d.facilityCode "facilityCode", d.weight "weight", d.deliveryAgent_barcode "deliveryAgentBarcode"
41944194
FROM Dewar d
4195+
LEFT JOIN DewarRegistry dr ON dr.facilityCode = d.facilityCode
41954196
INNER JOIN Shipping s ON s.shippingId = d.shippingId
4196-
INNER JOIN Proposal p ON p.proposalId = s.proposalId
4197+
INNER JOIN Proposal p ON p.proposalId = s.proposalId
41974198
INNER JOIN BLSession bs ON bs.proposalId = s.proposalId
41984199
INNER JOIN Session_has_Person shp ON bs.sessionId = shp.sessionId
41994200
INNER JOIN Person per ON per.personId = shp.personId
42004201
WHERE per.login = p_authLogin AND p.proposalCode = p_proposalCode AND p.proposalNumber = p_proposalNumber
42014202
GROUP BY d.dewarId, d.shippingId, d.code, d.comments, d.storageLocation,
42024203
d.dewarStatus, d.isStorageDewar, d.barCode, d.firstExperimentId,
4203-
d.type, d.facilityCode, d.weight, d.deliveryAgent_barcode;
4204+
dr.type, d.facilityCode, d.weight, d.deliveryAgent_barcode;
42044205
ELSE
42054206
SELECT
42064207
d.dewarId "id", d.shippingId "shippingId", d.code "name", d.comments "comments", d.storageLocation "storageLocation",
42074208
d.dewarStatus "status", d.isStorageDewar "isStorageDewar", d.barCode "barCode", d.firstExperimentId "firstSessionId",
4208-
d.type "type", d.facilityCode "facilityCode", d.weight "weight", d.deliveryAgent_barcode "deliveryAgentBarcode"
4209+
dr.type "type", d.facilityCode "facilityCode", d.weight "weight", d.deliveryAgent_barcode "deliveryAgentBarcode"
42094210
FROM Dewar d
4211+
LEFT JOIN DewarRegistry dr ON dr.facilityCode = d.facilityCode
42104212
INNER JOIN Shipping s ON s.shippingId = d.shippingId
4211-
INNER JOIN Proposal p ON p.proposalId = s.proposalId
4213+
INNER JOIN Proposal p ON p.proposalId = s.proposalId
42124214
WHERE p.proposalCode = p_proposalCode AND p.proposalNumber = p_proposalNumber;
42134215
END IF;
42144216

@@ -9996,6 +9998,112 @@ DELIMITER ;
99969998
/*!50003 SET character_set_results = @saved_cs_results */ ;
99979999
/*!50003 SET collation_connection = @saved_col_connection */ ;
999810000
/*!50003 SET @saved_sql_mode = @@sql_mode */ ;
10001+
/*!50003 SET sql_mode = 'STRICT_TRANS_TABLES,ERROR_FOR_DIVISION_BY_ZERO,NO_AUTO_CREATE_USER,NO_ENGINE_SUBSTITUTION' */ ;
10002+
/*!50003 DROP PROCEDURE IF EXISTS `upsert_dewar_v3` */;
10003+
/*!50003 SET @saved_cs_client = @@character_set_client */ ;
10004+
/*!50003 SET @saved_cs_results = @@character_set_results */ ;
10005+
/*!50003 SET @saved_col_connection = @@collation_connection */ ;
10006+
/*!50003 SET character_set_client = utf8mb3 */ ;
10007+
/*!50003 SET character_set_results = utf8mb3 */ ;
10008+
/*!50003 SET collation_connection = utf8mb3_general_ci */ ;
10009+
DELIMITER ;;
10010+
CREATE PROCEDURE `upsert_dewar_v3`(
10011+
10012+
INOUT p_id int(10) unsigned,
10013+
p_authLogin varchar(45),
10014+
p_shippingId int(10) unsigned,
10015+
p_name varchar(45),
10016+
p_comments tinytext,
10017+
p_storageLocation varchar(45),
10018+
p_status varchar(45),
10019+
p_isStorageDewar tinyint(1),
10020+
p_barcode varchar(45),
10021+
p_firstSessionId int(10) unsigned,
10022+
p_customsValue int(11) unsigned,
10023+
p_transportValue int(11) unsigned,
10024+
p_trackingNumberToSynchrotron varchar(30),
10025+
p_trackingNumberFromSynchrotron varchar(30),
10026+
p_facilityCode varchar(20),
10027+
p_weight float,
10028+
p_deliveryAgentBarcode varchar(30)
10029+
)
10030+
MODIFIES SQL DATA
10031+
COMMENT 'Inserts or updates info about a dewar/parcel (p_id).\nMandatory columns:\nFor insert: none\nFor update: p_id \nReturns: Record ID in p_id.'
10032+
BEGIN
10033+
DECLARE row_storageLocation varchar(45) DEFAULT NULL;
10034+
DECLARE row_dewarStatus varchar(45) DEFAULT NULL;
10035+
DECLARE row_count int unsigned DEFAULT 0;
10036+
10037+
IF p_storageLocation IS NULL THEN
10038+
SIGNAL SQLSTATE '45000' SET MYSQL_ERRNO=1644, MESSAGE_TEXT='Mandatory argument p_storageLocation is NULL';
10039+
END IF;
10040+
10041+
IF p_authLogin IS NOT NULL AND p_shippingId IS NOT NULL THEN
10042+
10043+
10044+
10045+
SELECT count(*) INTO row_count
10046+
FROM Shipping s
10047+
INNER JOIN BLSession bs ON bs.proposalId = s.proposalId
10048+
INNER JOIN Session_has_Person shp ON bs.sessionId = shp.sessionId
10049+
INNER JOIN Person p ON p.personId = shp.personId
10050+
WHERE p.login = p_authLogin AND s.shippingId = p_shippingId;
10051+
10052+
IF row_count = 0 THEN
10053+
SIGNAL SQLSTATE '02000'
10054+
SET MYSQL_ERRNO=1643, MESSAGE_TEXT = 'Dewar not in a shipping belonging to one of the p_authLogin Person sessions';
10055+
END IF;
10056+
END IF;
10057+
10058+
IF p_id IS NULL THEN
10059+
INSERT INTO Dewar(dewarId,shippingId,code,comments,storageLocation,dewarStatus,isStorageDewar,barCode,firstExperimentId,customsValue,transportValue,
10060+
trackingNumberToSynchrotron,trackingNumberFromSynchrotron,FACILITYCODE,weight,deliveryAgent_barcode)
10061+
VALUES (p_id, p_shippingId, p_name, p_comments, p_storageLocation, p_status, p_isStorageDewar, p_barcode, p_firstSessionId, p_customsValue, p_transportValue,
10062+
p_trackingNumberToSynchrotron, p_trackingNumberFromSynchrotron, p_facilityCode, p_weight, p_deliveryAgentBarcode);
10063+
SET p_id = LAST_INSERT_ID();
10064+
ELSE
10065+
10066+
SELECT storageLocation, dewarStatus INTO row_storageLocation, row_dewarStatus FROM Dewar WHERE dewarId = p_id;
10067+
10068+
UPDATE Dewar
10069+
SET shippingId = IFNULL(p_shippingId, shippingId),
10070+
code = IFNULL(p_name, code),
10071+
comments = IFNULL(p_comments, comments),
10072+
storageLocation = IFNULL(p_storageLocation, storageLocation),
10073+
dewarStatus = IFNULL(p_status, dewarStatus),
10074+
isStorageDewar = IFNULL(p_isStorageDewar, isStorageDewar),
10075+
barCode = IFNULL(p_barcode, barCode),
10076+
firstExperimentId = IFNULL(p_firstSessionId, firstExperimentId),
10077+
customsValue = IFNULL(p_customsValue, customsValue),
10078+
transportValue = IFNULL(p_transportValue, transportValue),
10079+
trackingNumberToSynchrotron = IFNULL(p_trackingNumberToSynchrotron, trackingNumberToSynchrotron),
10080+
trackingNumberFromSynchrotron = IFNULL(p_trackingNumberFromSynchrotron, trackingNumberFromSynchrotron),
10081+
FACILITYCODE = IFNULL(p_facilityCode, FACILITYCODE),
10082+
weight = IFNULL(p_weight, weight),
10083+
deliveryAgent_barcode = IFNULL(p_deliveryAgentBarcode, deliveryAgent_barcode)
10084+
WHERE dewarId = p_id;
10085+
10086+
10087+
IF row_storageLocation <> p_storageLocation OR row_dewarStatus <> p_status THEN
10088+
INSERT INTO DewarTransportHistory (dewarId, dewarStatus, storageLocation, arrivalDate)
10089+
VALUES (p_id, p_status, p_storageLocation, NOW());
10090+
END IF;
10091+
10092+
10093+
IF row_storageLocation <> p_storageLocation THEN
10094+
10095+
UPDATE Container
10096+
SET sampleChangerLocation = '', containerStatus = 'at facility'
10097+
WHERE dewarId = p_id;
10098+
END IF;
10099+
END IF;
10100+
END ;;
10101+
DELIMITER ;
10102+
/*!50003 SET sql_mode = @saved_sql_mode */ ;
10103+
/*!50003 SET character_set_client = @saved_cs_client */ ;
10104+
/*!50003 SET character_set_results = @saved_cs_results */ ;
10105+
/*!50003 SET collation_connection = @saved_col_connection */ ;
10106+
/*!50003 SET @saved_sql_mode = @@sql_mode */ ;
999910107
/*!50003 SET sql_mode = '' */ ;
1000010108
/*!50003 DROP PROCEDURE IF EXISTS `upsert_energy_scan` */;
1000110109
/*!50003 SET @saved_cs_client = @@character_set_client */ ;

schemas/ispyb/tables.sql

Lines changed: 47 additions & 2 deletions
Original file line numberDiff line numberDiff line change
@@ -614,12 +614,12 @@ CREATE TABLE `BLSamplePosition` (
614614
`posX` double DEFAULT NULL,
615615
`posY` double DEFAULT NULL,
616616
`posZ` double DEFAULT NULL,
617-
`recordTimeStamp` datetime DEFAULT NULL COMMENT 'Creation or last update date/time',
617+
`recordTimeStamp` datetime DEFAULT current_timestamp(),
618618
`positionType` enum('dispensing') DEFAULT NULL COMMENT 'Type of marked position (e.g.: dispensing location)',
619619
PRIMARY KEY (`blSamplePositionId`),
620620
KEY `BLSamplePosition_fk_blSampleId` (`blSampleId`),
621621
CONSTRAINT `BLSamplePosition_fk_blSampleId` FOREIGN KEY (`blSampleId`) REFERENCES `BLSample` (`blSampleId`)
622-
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci;
622+
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4;
623623
/*!40101 SET character_set_client = @saved_cs_client */;
624624
DROP TABLE IF EXISTS `BLSampleType`;
625625
/*!40101 SET @saved_cs_client = @@character_set_client */;
@@ -672,6 +672,18 @@ CREATE TABLE `BLSample_has_EnergyScan` (
672672
CONSTRAINT `BLSample_has_EnergyScan_ibfk_2` FOREIGN KEY (`energyScanId`) REFERENCES `EnergyScan` (`energyScanId`) ON DELETE CASCADE ON UPDATE CASCADE
673673
) ENGINE=InnoDB DEFAULT CHARSET=latin1;
674674
/*!40101 SET character_set_client = @saved_cs_client */;
675+
DROP TABLE IF EXISTS `BLSample_has_Ligand`;
676+
/*!40101 SET @saved_cs_client = @@character_set_client */;
677+
/*!40101 SET character_set_client = utf8mb4 */;
678+
CREATE TABLE `BLSample_has_Ligand` (
679+
`blSampleId` int(10) unsigned NOT NULL,
680+
`ligandId` int(11) unsigned NOT NULL,
681+
PRIMARY KEY (`blSampleId`,`ligandId`),
682+
KEY `BLSample_has_Ligand_fk2` (`ligandId`),
683+
CONSTRAINT `BLSample_has_Ligand_fk1` FOREIGN KEY (`blSampleId`) REFERENCES `BLSample` (`blSampleId`) ON DELETE CASCADE ON UPDATE CASCADE,
684+
CONSTRAINT `BLSample_has_Ligand_fk2` FOREIGN KEY (`ligandId`) REFERENCES `Ligand` (`ligandId`) ON DELETE CASCADE ON UPDATE CASCADE
685+
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COMMENT='Junction table for BLSample and Ligand';
686+
/*!40101 SET character_set_client = @saved_cs_client */;
675687
DROP TABLE IF EXISTS `BLSample_has_Positioner`;
676688
/*!40101 SET @saved_cs_client = @@character_set_client */;
677689
/*!40101 SET character_set_client = utf8mb4 */;
@@ -709,6 +721,7 @@ CREATE TABLE `BLSession` (
709721
`archived` tinyint(1) DEFAULT 0 COMMENT 'The data for the session is archived and no longer available on disk',
710722
`riskRating` enum('Low','Medium','High','Not Permitted') DEFAULT NULL COMMENT 'ERA in user admin system',
711723
`purgedProcessedData` tinyint(1) DEFAULT 0 COMMENT 'Flag to indicate whether the processed folder in the associated visit directory has been purged',
724+
`icatId` int(11) unsigned DEFAULT NULL COMMENT 'The internal ICAT ID for this BLSession',
712725
PRIMARY KEY (`sessionId`),
713726
UNIQUE KEY `proposalId` (`proposalId`,`visit_number`),
714727
KEY `Session_FKIndex2` (`beamLineSetupId`),
@@ -1677,6 +1690,7 @@ CREATE TABLE `DewarRegistry` (
16771690
`purchaseDate` datetime DEFAULT NULL,
16781691
`bltimestamp` datetime NOT NULL DEFAULT current_timestamp(),
16791692
`manufacturerSerialNumber` varchar(15) DEFAULT NULL COMMENT 'Dewar serial number as given by manufacturer. Used to be typically 5 or 6 digits, more likely to be 11 alphanumeric chars in future',
1693+
`type` enum('Dewar','Toolbox','Thermal Shipper') NOT NULL DEFAULT 'Dewar',
16801694
PRIMARY KEY (`dewarRegistryId`),
16811695
UNIQUE KEY `facilityCode` (`facilityCode`),
16821696
KEY `DewarRegistry_ibfk_1` (`proposalId`),
@@ -2195,6 +2209,35 @@ CREATE TABLE `Laboratory` (
21952209
PRIMARY KEY (`laboratoryId`)
21962210
) ENGINE=InnoDB DEFAULT CHARSET=latin1;
21972211
/*!40101 SET character_set_client = @saved_cs_client */;
2212+
DROP TABLE IF EXISTS `Ligand`;
2213+
/*!40101 SET @saved_cs_client = @@character_set_client */;
2214+
/*!40101 SET character_set_client = utf8mb4 */;
2215+
CREATE TABLE `Ligand` (
2216+
`ligandId` int(11) unsigned NOT NULL AUTO_INCREMENT,
2217+
`proposalId` int(10) unsigned NOT NULL COMMENT 'References Proposal table',
2218+
`name` varchar(30) NOT NULL COMMENT 'Ligand name',
2219+
`SMILES` varchar(400) DEFAULT NULL COMMENT 'Chemical structure',
2220+
`libraryName` varchar(30) DEFAULT NULL COMMENT 'Name of ligand library, to preserve provenance',
2221+
`libraryBatchNumber` varchar(30) DEFAULT NULL COMMENT 'Batch number of library, to preserve provenance',
2222+
`plateBarcode` varchar(30) DEFAULT NULL COMMENT 'Specific barcode of the plate it came from, to preserve provenance',
2223+
`sourceWell` varchar(30) DEFAULT NULL COMMENT 'Location within that plate, to preserve provenance',
2224+
PRIMARY KEY (`ligandId`),
2225+
KEY `Ligand_fk_proposalId` (`proposalId`),
2226+
CONSTRAINT `Ligand_fk_proposalId` FOREIGN KEY (`proposalId`) REFERENCES `Proposal` (`proposalId`) ON DELETE CASCADE ON UPDATE CASCADE
2227+
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COMMENT='Ligands in biochemistry are substances that bind to biomolecules';
2228+
/*!40101 SET character_set_client = @saved_cs_client */;
2229+
DROP TABLE IF EXISTS `Ligand_has_PDB`;
2230+
/*!40101 SET @saved_cs_client = @@character_set_client */;
2231+
/*!40101 SET character_set_client = utf8mb4 */;
2232+
CREATE TABLE `Ligand_has_PDB` (
2233+
`ligandId` int(11) unsigned NOT NULL,
2234+
`pdbId` int(11) unsigned NOT NULL,
2235+
PRIMARY KEY (`ligandId`,`pdbId`),
2236+
KEY `Ligand_Has_PDB_fk2` (`pdbId`),
2237+
CONSTRAINT `Ligand_Has_PDB_fk1` FOREIGN KEY (`ligandId`) REFERENCES `Ligand` (`ligandId`) ON DELETE CASCADE ON UPDATE CASCADE,
2238+
CONSTRAINT `Ligand_Has_PDB_fk2` FOREIGN KEY (`pdbId`) REFERENCES `PDB` (`pdbId`) ON DELETE CASCADE ON UPDATE CASCADE
2239+
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COMMENT='Junction table for Ligand and PDB';
2240+
/*!40101 SET character_set_client = @saved_cs_client */;
21982241
DROP TABLE IF EXISTS `MXMRRun`;
21992242
/*!40101 SET @saved_cs_client = @@character_set_client */;
22002243
/*!40101 SET character_set_client = utf8mb4 */;
@@ -2414,6 +2457,8 @@ CREATE TABLE `ParticleClassification` (
24142457
`bFactorFitQuadratic` float DEFAULT NULL COMMENT 'Quadratic coefficient of quadratic fit to refinement resolution against the logarithm of the number of particles',
24152458
`angularEfficiency` double DEFAULT NULL COMMENT 'Variation in resolution across different angles, 1-2sig/mean',
24162459
`suggestedTilt` double DEFAULT NULL COMMENT 'Suggested stage tilt angle to improve angular efficiency. Unit: degrees',
2460+
`pixelLocationX` int(11) DEFAULT NULL COMMENT 'pixel location of tomogram centre on search map image (x)',
2461+
`pixelLocationY` int(11) DEFAULT NULL COMMENT 'pixel location of tomogram centre on search map image (y)',
24172462
PRIMARY KEY (`particleClassificationId`),
24182463
KEY `ParticleClassification_fk_particleClassificationGroupId` (`particleClassificationGroupId`),
24192464
CONSTRAINT `ParticleClassification_fk_particleClassificationGroupId` FOREIGN KEY (`particleClassificationGroupId`) REFERENCES `ParticleClassificationGroup` (`particleClassificationGroupId`) ON DELETE CASCADE ON UPDATE CASCADE

0 commit comments

Comments
 (0)