Skip to content

Commit

Permalink
Merge pull request #39 from DiamondLightSource/SCI-7452-plus
Browse files Browse the repository at this point in the history
Various smaller issues / tasks:

- Method + test for retrieve_sessions_for_person_login (SCI-7452) 
- Updated SP retrieve_processing_programs_for_job_id to include status
- Improved logic for SPs update_container_assign and upsert_dewar
- More testing for shipping.upsert_dewar
  • Loading branch information
Anthchirp authored Aug 7, 2018
2 parents 6ba1272 + d23554d commit ecd7b89
Show file tree
Hide file tree
Showing 4 changed files with 135 additions and 46 deletions.
156 changes: 114 additions & 42 deletions conf/routines.sql
Original file line number Diff line number Diff line change
Expand Up @@ -2712,11 +2712,12 @@ DELIMITER ;
DELIMITER ;;
CREATE PROCEDURE `retrieve_processing_programs_for_job_id`(p_id int unsigned)
READS SQL DATA
COMMENT 'Returns a multi-row result-set with processing program instances'
COMMENT 'Returns a multi-row result-set with processing program instances for the given processing job ID'
BEGIN
IF p_id IS NOT NULL THEN
SELECT autoProcProgramId "id", processingCommandLine "commandLine", processingPrograms "programs", processingMessage "message",
processingStartTime "startTime", processingEndTime "endTime", processingEnvironment "environment",
SELECT autoProcProgramId "id", processingCommandLine "commandLine", processingPrograms "programs",
processingStatus "status", processingMessage "message", processingStartTime "startTime",
processingEndTime "endTime", processingEnvironment "environment",
recordTimeStamp "recordTimeStamp", processingJobId "jobId"
FROM AutoProcProgram
WHERE processingJobId = p_id
Expand Down Expand Up @@ -2905,6 +2906,37 @@ DELIMITER ;
/*!50003 SET character_set_client = @saved_cs_client */ ;
/*!50003 SET character_set_results = @saved_cs_results */ ;
/*!50003 SET collation_connection = @saved_col_connection */ ;
/*!50003 DROP PROCEDURE IF EXISTS `retrieve_sessions_for_person_login` */;
/*!50003 SET @saved_cs_client = @@character_set_client */ ;
/*!50003 SET @saved_cs_results = @@character_set_results */ ;
/*!50003 SET @saved_col_connection = @@collation_connection */ ;
/*!50003 SET character_set_client = utf8 */ ;
/*!50003 SET character_set_results = utf8 */ ;
/*!50003 SET collation_connection = utf8_general_ci */ ;
/*!50003 SET @saved_sql_mode = @@sql_mode */ ;
/*!50003 SET sql_mode = '' */ ;
DELIMITER ;;
CREATE PROCEDURE `retrieve_sessions_for_person_login`(p_login varchar(45))
READS SQL DATA
COMMENT 'Returns a multi-row result-set with info about the sessions associated with a person with login=p_login'
BEGIN
IF p_login IS NOT NULL THEN
SELECT bs.sessionId "id", bs.proposalId "proposalId", bs.startDate "startDate", bs.endDate "endDate",
bs.beamlineName "beamline", bs.visit_number "sessionNumber", bs.comments "comments", shp.role "personRoleOnSession", shp.remote "personRemoteOnSession"
FROM BLSession bs
INNER JOIN Session_has_Person shp on shp.sessionId = bs.sessionId
INNER JOIN Person p on p.personId = shp.personId
WHERE p.login = p_login
ORDER BY bs.startDate;
ELSE
SIGNAL SQLSTATE '45000' SET MYSQL_ERRNO=1644, MESSAGE_TEXT='Mandatory argument p_login can not be NULL';
END IF;
END ;;
DELIMITER ;
/*!50003 SET sql_mode = @saved_sql_mode */ ;
/*!50003 SET character_set_client = @saved_cs_client */ ;
/*!50003 SET character_set_results = @saved_cs_results */ ;
/*!50003 SET collation_connection = @saved_col_connection */ ;
/*!50003 DROP PROCEDURE IF EXISTS `retrieve_session_id` */;
/*!50003 SET @saved_cs_client = @@character_set_client */ ;
/*!50003 SET @saved_cs_results = @@character_set_results */ ;
Expand Down Expand Up @@ -2959,46 +2991,65 @@ DELIMITER ;
DELIMITER ;;
CREATE PROCEDURE `update_container_assign`(IN p_beamline varchar(20), IN p_registry_barcode varchar(45), IN p_position int)
MODIFIES SQL DATA
COMMENT 'Toggles the ''assign'' status of a container (barcode = p_barcode)'
COMMENT 'Toggles the ''assign'' status of a container (barcode = p_barcode) between ''processing'' and ''at facility''. Sets the sampleChangerLocation, beamlineLocation. If the containerStatus is set to ''processing'' then sets the same status for its dewar and shipping.'
BEGIN
DECLARE row_containerId int(10) unsigned DEFAULT NULL;
DECLARE row_containerStatus varchar(45) DEFAULT NULL;
DECLARE row_dewarId int(10) unsigned DEFAULT NULL;
DECLARE row_beamlineLocation varchar(20) DEFAULT NULL;
DECLARE row_sampleChangerLocation varchar(20) DEFAULT NULL;
DECLARE row_proposalId int(10) unsigned DEFAULT NULL;

IF NOT (p_registry_barcode IS NULL) THEN
START TRANSACTION;

SELECT c.containerId, c.containerStatus, c.dewarId INTO row_containerId, row_containerStatus, row_dewarId
SELECT c.containerId, c.containerStatus, c.dewarId, c.beamlineLocation, c.sampleChangerLocation, s.proposalId
INTO row_containerId, row_containerStatus, row_dewarId, row_beamlineLocation, row_sampleChangerLocation, row_proposalId
FROM Container c
INNER JOIN ContainerRegistry cr ON c.containerRegistryId = cr.containerRegistryId
INNER JOIN Dewar d ON d.dewarId = c.dewarId
INNER JOIN Shipping s ON s.shippingId = d.shippingId
WHERE cr.barcode = p_registry_barcode
ORDER BY c.containerId DESC
LIMIT 1;

IF NOT row_containerId IS NULL THEN

UPDATE Container c
INNER JOIN Dewar d ON d.dewarId = c.dewarId
INNER JOIN Shipping s ON s.shippingId = d.shippingId
SET
c.sampleChangerLocation = IF(row_containerStatus='processing', '', p_position),
c.beamlineLocation = p_beamline,
c.containerStatus = IF(row_containerStatus='processing', 'at DLS', 'processing'),
d.dewarStatus = IF(row_containerStatus='processing', d.dewarStatus, 'processing'),
d.storageLocation = IF(row_containerStatus='processing', d.storageLocation, p_beamline),
s.shippingStatus = IF(row_containerStatus='processing', s.shippingStatus, 'processing')
WHERE
c.containerId = row_containerId;

IF row_containerStatus <> 'processing' THEN

INSERT INTO DewarTransportHistory (dewarId, dewarStatus, storageLocation, arrivalDate)
VALUES (row_dewarId, 'processing', p_beamline, NOW());
END IF;
IF NOT row_containerId IS NULL THEN
IF row_containerStatus <> 'processing' OR (row_beamlineLocation = p_beamline AND row_sampleChangerLocation = p_position) THEN


UPDATE Container c
INNER JOIN Dewar d ON d.dewarId = c.dewarId
INNER JOIN Shipping s ON s.shippingId = d.shippingId
SET
c.sampleChangerLocation = IF(row_containerStatus='processing', '', p_position),
c.beamlineLocation = p_beamline,
c.containerStatus = IF(row_containerStatus='processing', 'at facility', 'processing'),
d.dewarStatus = IF(row_containerStatus='processing', d.dewarStatus, 'processing'),
d.storageLocation = IF(row_containerStatus='processing', d.storageLocation, p_beamline),
s.shippingStatus = IF(row_containerStatus='processing', s.shippingStatus, 'processing')
WHERE
c.containerId = row_containerId;

IF row_containerStatus <> 'processing' THEN


UPDATE Container c
INNER JOIN Dewar d ON d.dewarId = c.dewarId
INNER JOIN Shipping s ON s.shippingId = d.shippingId
SET c.containerStatus = 'at facility'
WHERE s.shippingId = row_proposalId AND c.beamlineLocation = p_beamline AND
c.sampleChangerLocation = p_position AND c.containerId <> row_containerId;


INSERT INTO ContainerHistory (containerId, location, status, beamlineName)
VALUES (row_containerId, p_position, IF(row_containerStatus='processing', 'at DLS', 'processing'), p_beamline);

INSERT INTO DewarTransportHistory (dewarId, dewarStatus, storageLocation, arrivalDate)
VALUES (row_dewarId, 'processing', p_beamline, NOW());
END IF;


INSERT INTO ContainerHistory (containerId, location, status, beamlineName)
VALUES (row_containerId, p_position, IF(row_containerStatus='processing', 'at facility', 'processing'), p_beamline);
END IF;
ELSE
SIGNAL SQLSTATE '02000' SET MYSQL_ERRNO=1643, MESSAGE_TEXT='Container with p_registry_barcode not found';
END IF;
Expand Down Expand Up @@ -4045,15 +4096,27 @@ CREATE PROCEDURE `upsert_dewar`(
p_deliveryAgentBarcode varchar(30)
)
MODIFIES SQL DATA
COMMENT 'Inserts or updates info about a dewar/parcel (p_id).\nMandatory c'
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.'
BEGIN
IF p_type IS NOT NULL THEN
INSERT INTO Dewar(dewarId,shippingId,code,comments,storageLocation,dewarStatus,isStorageDewar,barCode,firstExperimentId,customsValue,transportValue,
trackingNumberToSynchrotron,trackingNumberFromSynchrotron,`type`,FACILITYCODE,weight,deliveryAgent_barcode)
VALUES (p_id, p_shippingId, p_name, p_comments, p_storageLocation, p_status, p_isStorageDewar, p_barcode, p_firstSessionId, p_customsValue, p_transportValue,
p_trackingNumberToSynchrotron, p_trackingNumberFromSynchrotron, p_type, p_facilityCode, p_weight, p_deliveryAgentBarcode)
ON DUPLICATE KEY UPDATE
shippingId = IFNULL(p_shippingId, shippingId),
DECLARE row_storageLocation varchar(45) DEFAULT NULL;
DECLARE row_dewarStatus varchar(45) DEFAULT NULL;

IF p_id IS NULL THEN
IF p_type IS NOT NULL THEN
INSERT INTO Dewar(dewarId,shippingId,code,comments,storageLocation,dewarStatus,isStorageDewar,barCode,firstExperimentId,customsValue,transportValue,
trackingNumberToSynchrotron,trackingNumberFromSynchrotron,`type`,FACILITYCODE,weight,deliveryAgent_barcode)
VALUES (p_id, p_shippingId, p_name, p_comments, p_storageLocation, p_status, p_isStorageDewar, p_barcode, p_firstSessionId, p_customsValue, p_transportValue,
p_trackingNumberToSynchrotron, p_trackingNumberFromSynchrotron, p_type, p_facilityCode, p_weight, p_deliveryAgentBarcode);
SET p_id = LAST_INSERT_ID();
ELSE
SIGNAL SQLSTATE '45000' SET MYSQL_ERRNO=1644, MESSAGE_TEXT='Mandatory argument is NULL: p_type must be non-NULL.';
END IF;
ELSE

SELECT storageLocation, dewarStatus INTO row_storageLocation, row_dewarStatus FROM Dewar WHERE dewarId = p_id;

UPDATE Dewar
SET shippingId = IFNULL(p_shippingId, shippingId),
code = IFNULL(p_name, code),
comments = IFNULL(p_comments, comments),
storageLocation = IFNULL(p_storageLocation, storageLocation),
Expand All @@ -4068,14 +4131,23 @@ BEGIN
`type` = IFNULL(p_type, `type`),
FACILITYCODE = IFNULL(p_facilityCode, FACILITYCODE),
weight = IFNULL(p_weight, weight),
deliveryAgent_barcode = IFNULL(p_deliveryAgentBarcode, deliveryAgent_barcode);
deliveryAgent_barcode = IFNULL(p_deliveryAgentBarcode, deliveryAgent_barcode)
WHERE dewarId = p_id;

IF p_id IS NULL THEN
SET p_id = LAST_INSERT_ID();

IF row_storageLocation <> p_storageLocation OR row_dewarStatus <> p_status THEN
INSERT INTO DewarTransportHistory (dewarId, dewarStatus, storageLocation, arrivalDate)
VALUES (p_id, p_status, p_storageLocation, NOW());
END IF;


IF row_storageLocation <> p_storageLocation THEN

UPDATE Container
SET sampleChangerLocation = '', containerStatus = 'at facility'
WHERE dewarId = p_id;
END IF;
END IF;
ELSE
SIGNAL SQLSTATE '45000' SET MYSQL_ERRNO=1644, MESSAGE_TEXT='Mandatory argument is NULL: p_type must be non-NULL.';
END IF;
END ;;
DELIMITER ;
/*!50003 SET sql_mode = @saved_sql_mode */ ;
Expand Down Expand Up @@ -5499,4 +5571,4 @@ DELIMITER ;
/*!40101 SET COLLATION_CONNECTION=@OLD_COLLATION_CONNECTION */;
/*!40111 SET SQL_NOTES=@OLD_SQL_NOTES */;

-- Dump completed on 2018-06-11 16:03:38
-- Dump completed on 2018-06-19 23:20:09
4 changes: 4 additions & 0 deletions ispyb/sp/core.py
Original file line number Diff line number Diff line change
Expand Up @@ -114,6 +114,10 @@ def retrieve_current_sessions(self, beamline, tolerance_mins=0):
'''Get a result-set with the currently active sessions on the given beamline.'''
return self.get_connection().call_sp_retrieve(procname='retrieve_current_sessions', args=(beamline,tolerance_mins))

def retrieve_sessions_for_person_login(self, login):
'''Get a result-set with the sessions associated with the given unique person login.'''
return self.get_connection().call_sp_retrieve(procname='retrieve_sessions_for_person_login', args=(login,))

def retrieve_current_sessions_for_person(self, beamline, fed_id, tolerance_mins=0):
'''Get a result-set with the currently active sessions on the given beamline.'''
return self.get_connection().call_sp_retrieve(procname='retrieve_current_sessions_for_person', args=(beamline, fed_id, tolerance_mins))
Expand Down
5 changes: 5 additions & 0 deletions tests/test_core.py
Original file line number Diff line number Diff line change
Expand Up @@ -97,6 +97,11 @@ def test_retrieve_current_sessions(testconfig):
rs = conn.core.retrieve_current_sessions('i03', 24*60*30000)
assert len(rs) > 0

def test_retrieve_sessions_for_person_login(testconfig):
with ispyb.open(testconfig) as conn:
rs = conn.core.retrieve_sessions_for_person_login('boaty')
assert len(rs) > 0

def test_retrieve_current_sessions_for_person(testconfig):
with ispyb.open(testconfig) as conn:
rs = conn.core.retrieve_current_sessions_for_person('i03', 'boaty', tolerance_mins=24*60*30000)
Expand Down
16 changes: 12 additions & 4 deletions tests/test_shipping.py
Original file line number Diff line number Diff line change
Expand Up @@ -16,11 +16,19 @@ def test_upsert_dewar(testconfig):
params['name'] = 'Test-dewar'
params['comments'] = 'This is a test ...'
#params['barcode'] = 'cm1-1-i03-0023151' # must be unique! Or not set ...
params['status'] = 'at DLS'
params['status'] = 'at facility'
params['type'] = 'Dewar' # only Dewar and Toolbox allowed in table definition
sid = shipping.upsert_dewar(list(params.values()))
assert sid is not None
assert sid > 0
did = shipping.upsert_dewar(list(params.values()))
assert did is not None
assert did > 0

params = shipping.get_dewar_params()
params['id'] = did
params['status'] = 'processing'
params['storageLocation'] = 'i04-1'
did2 = shipping.upsert_dewar(list(params.values()))
assert did2 is not None
assert did2 > 0

def test_retrieve_dewars(testconfig):
with ispyb.open(testconfig) as conn:
Expand Down

0 comments on commit ecd7b89

Please sign in to comment.