@@ -4190,25 +4190,27 @@ BEGIN
4190
4190
SELECT
4191
4191
d.dewarId "id", d.shippingId "shippingId", d.code "name", d.comments "comments", d.storageLocation "storageLocation",
4192
4192
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"
4194
4194
FROM Dewar d
4195
+ LEFT JOIN DewarRegistry dr ON dr.facilityCode = d.facilityCode
4195
4196
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
4197
4198
INNER JOIN BLSession bs ON bs.proposalId = s.proposalId
4198
4199
INNER JOIN Session_has_Person shp ON bs.sessionId = shp.sessionId
4199
4200
INNER JOIN Person per ON per.personId = shp.personId
4200
4201
WHERE per.login = p_authLogin AND p.proposalCode = p_proposalCode AND p.proposalNumber = p_proposalNumber
4201
4202
GROUP BY d.dewarId, d.shippingId, d.code, d.comments, d.storageLocation,
4202
4203
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;
4204
4205
ELSE
4205
4206
SELECT
4206
4207
d.dewarId "id", d.shippingId "shippingId", d.code "name", d.comments "comments", d.storageLocation "storageLocation",
4207
4208
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"
4209
4210
FROM Dewar d
4211
+ LEFT JOIN DewarRegistry dr ON dr.facilityCode = d.facilityCode
4210
4212
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
4212
4214
WHERE p.proposalCode = p_proposalCode AND p.proposalNumber = p_proposalNumber;
4213
4215
END IF;
4214
4216
@@ -9996,6 +9998,112 @@ DELIMITER ;
9996
9998
/*!50003 SET character_set_results = @saved_cs_results */ ;
9997
9999
/*!50003 SET collation_connection = @saved_col_connection */ ;
9998
10000
/*!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 */ ;
9999
10107
/*!50003 SET sql_mode = '' */ ;
10000
10108
/*!50003 DROP PROCEDURE IF EXISTS `upsert_energy_scan` */;
10001
10109
/*!50003 SET @saved_cs_client = @@character_set_client */ ;
0 commit comments