|
| 1 | +-- Note: upsert_dewar_v3 is the same as upsert_dewar_v2 except it doesn't set the deprecated type column |
| 2 | +-- Test: |
| 3 | +-- SET @id = NULL; |
| 4 | +-- CALL upsert_dewar_v3(@id, 'boaty', 6988, 'boatys dewar', NULL, '1', 'at facility', 0, 'DLS-MX-00101', NULL, 0, 0, NULL, NULL, 'DLS-MX-00101', 5, NULL); |
| 5 | +-- |
| 6 | + |
| 7 | +DELIMITER ;; |
| 8 | + |
| 9 | +CREATE OR REPLACE DEFINER=`ispyb_root`@`%` PROCEDURE `upsert_dewar_v3`( |
| 10 | + |
| 11 | + INOUT p_id int(10) unsigned, |
| 12 | + p_authLogin varchar(45), |
| 13 | + p_shippingId int(10) unsigned, |
| 14 | + p_name varchar(45), |
| 15 | + p_comments tinytext, |
| 16 | + p_storageLocation varchar(45), |
| 17 | + p_status varchar(45), |
| 18 | + p_isStorageDewar tinyint(1), |
| 19 | + p_barcode varchar(45), |
| 20 | + p_firstSessionId int(10) unsigned, |
| 21 | + p_customsValue int(11) unsigned, |
| 22 | + p_transportValue int(11) unsigned, |
| 23 | + p_trackingNumberToSynchrotron varchar(30), |
| 24 | + p_trackingNumberFromSynchrotron varchar(30), |
| 25 | + p_facilityCode varchar(20), |
| 26 | + p_weight float, |
| 27 | + p_deliveryAgentBarcode varchar(30) |
| 28 | + ) |
| 29 | + MODIFIES SQL DATA |
| 30 | + 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.' |
| 31 | +BEGIN |
| 32 | + DECLARE row_storageLocation varchar(45) DEFAULT NULL; |
| 33 | + DECLARE row_dewarStatus varchar(45) DEFAULT NULL; |
| 34 | + DECLARE row_count int unsigned DEFAULT 0; |
| 35 | + |
| 36 | + IF p_storageLocation IS NULL THEN |
| 37 | + SIGNAL SQLSTATE '45000' SET MYSQL_ERRNO=1644, MESSAGE_TEXT='Mandatory argument p_storageLocation is NULL'; |
| 38 | + END IF; |
| 39 | + |
| 40 | + IF p_authLogin IS NOT NULL AND p_shippingId IS NOT NULL THEN |
| 41 | + |
| 42 | + -- Authorise only if the person (p_authLogin) is a member of a session on the proposal of the shipping that the dewar belongs to. |
| 43 | + -- If the dewar doesn't have a shipping this will fail. |
| 44 | + SELECT count(*) INTO row_count |
| 45 | + FROM Shipping s |
| 46 | + INNER JOIN BLSession bs ON bs.proposalId = s.proposalId |
| 47 | + INNER JOIN Session_has_Person shp ON bs.sessionId = shp.sessionId |
| 48 | + INNER JOIN Person p ON p.personId = shp.personId |
| 49 | + WHERE p.login = p_authLogin AND s.shippingId = p_shippingId; |
| 50 | + |
| 51 | + IF row_count = 0 THEN |
| 52 | + SIGNAL SQLSTATE '02000' |
| 53 | + SET MYSQL_ERRNO=1643, MESSAGE_TEXT = 'Dewar not in a shipping belonging to one of the p_authLogin Person sessions'; |
| 54 | + END IF; |
| 55 | + END IF; |
| 56 | + |
| 57 | + IF p_id IS NULL THEN |
| 58 | + INSERT INTO Dewar(dewarId,shippingId,code,comments,storageLocation,dewarStatus,isStorageDewar,barCode,firstExperimentId,customsValue,transportValue, |
| 59 | + trackingNumberToSynchrotron,trackingNumberFromSynchrotron,FACILITYCODE,weight,deliveryAgent_barcode) |
| 60 | + VALUES (p_id, p_shippingId, p_name, p_comments, p_storageLocation, p_status, p_isStorageDewar, p_barcode, p_firstSessionId, p_customsValue, p_transportValue, |
| 61 | + p_trackingNumberToSynchrotron, p_trackingNumberFromSynchrotron, p_facilityCode, p_weight, p_deliveryAgentBarcode); |
| 62 | + SET p_id = LAST_INSERT_ID(); |
| 63 | + ELSE |
| 64 | + |
| 65 | + SELECT storageLocation, dewarStatus INTO row_storageLocation, row_dewarStatus FROM Dewar WHERE dewarId = p_id; |
| 66 | + |
| 67 | + UPDATE Dewar |
| 68 | + SET shippingId = IFNULL(p_shippingId, shippingId), |
| 69 | + code = IFNULL(p_name, code), |
| 70 | + comments = IFNULL(p_comments, comments), |
| 71 | + storageLocation = IFNULL(p_storageLocation, storageLocation), |
| 72 | + dewarStatus = IFNULL(p_status, dewarStatus), |
| 73 | + isStorageDewar = IFNULL(p_isStorageDewar, isStorageDewar), |
| 74 | + barCode = IFNULL(p_barcode, barCode), |
| 75 | + firstExperimentId = IFNULL(p_firstSessionId, firstExperimentId), |
| 76 | + customsValue = IFNULL(p_customsValue, customsValue), |
| 77 | + transportValue = IFNULL(p_transportValue, transportValue), |
| 78 | + trackingNumberToSynchrotron = IFNULL(p_trackingNumberToSynchrotron, trackingNumberToSynchrotron), |
| 79 | + trackingNumberFromSynchrotron = IFNULL(p_trackingNumberFromSynchrotron, trackingNumberFromSynchrotron), |
| 80 | + FACILITYCODE = IFNULL(p_facilityCode, FACILITYCODE), |
| 81 | + weight = IFNULL(p_weight, weight), |
| 82 | + deliveryAgent_barcode = IFNULL(p_deliveryAgentBarcode, deliveryAgent_barcode) |
| 83 | + WHERE dewarId = p_id; |
| 84 | + |
| 85 | + -- If a dewar is moved or the status has changed then ... |
| 86 | + IF row_storageLocation <> p_storageLocation OR row_dewarStatus <> p_status THEN |
| 87 | + INSERT INTO DewarTransportHistory (dewarId, dewarStatus, storageLocation, arrivalDate) |
| 88 | + VALUES (p_id, p_status, p_storageLocation, NOW()); |
| 89 | + END IF; |
| 90 | + |
| 91 | + -- If a dewar is moved then ... |
| 92 | + IF row_storageLocation <> p_storageLocation THEN |
| 93 | + -- any pucks within the dewar should have sampleChangerLocation set to blank and the containerStatus field set to "at facility" |
| 94 | + UPDATE Container |
| 95 | + SET sampleChangerLocation = '', containerStatus = 'at facility' |
| 96 | + WHERE dewarId = p_id; |
| 97 | + END IF; |
| 98 | + END IF; |
| 99 | +END;; |
| 100 | +DELIMITER ; |
0 commit comments