From fe7c0429c72431f645e2380d754c095d1e736568 Mon Sep 17 00:00:00 2001 From: Karl Levik Date: Mon, 5 Jun 2023 16:21:15 +0100 Subject: [PATCH] New stored procedure upsert_dc_grid_v2 using params p_micronsPerPixelX,Y (#198) * New sproc upsert_dc_grid_v2 using params p_micronsPerPixelX,Y * Add grant to execute new sproc upsert_dc_grid_v2 * Refresh schema files with new sproc upsert_dc_grid_v2 * Update history with new stored procedure * Bump up version to 2.1.0 --- HISTORY.rst | 5 ++ grants/ispyb_acquisition.sql | 1 + schemas/ispyb/lookups.sql | 5 +- schemas/ispyb/routines.sql | 63 ++++++++++++++++++- .../stored_programs/sp_upsert_dc_grid_v2.sql | 48 ++++++++++++++ .../2023_06_05_AdminVar_bump_version.sql | 5 ++ 6 files changed, 122 insertions(+), 5 deletions(-) create mode 100644 schemas/ispyb/stored_programs/sp_upsert_dc_grid_v2.sql create mode 100644 schemas/ispyb/updates/2023_06_05_AdminVar_bump_version.sql diff --git a/HISTORY.rst b/HISTORY.rst index ec87bd01..dfa211ad 100644 --- a/HISTORY.rst +++ b/HISTORY.rst @@ -5,6 +5,11 @@ History Unreleased / master ------------------- +2.1.0 (2023-06-05) +------------------- + +* New stored procedure ``upsert_dc_grid_v2`` and ``EXECUTE`` permission on it for the relevant role + 2.0.0 (2023-05-15) ------------------- diff --git a/grants/ispyb_acquisition.sql b/grants/ispyb_acquisition.sql index 6169aa83..6c789306 100644 --- a/grants/ispyb_acquisition.sql +++ b/grants/ispyb_acquisition.sql @@ -34,6 +34,7 @@ GRANT EXECUTE ON PROCEDURE update_dc_machine TO 'ispyb_acquisition'; GRANT EXECUTE ON PROCEDURE upsert_sample_image_analysis TO 'ispyb_acquisition'; GRANT EXECUTE ON PROCEDURE upsert_dcg_grid TO 'ispyb_acquisition'; GRANT EXECUTE ON PROCEDURE upsert_dc_grid TO 'ispyb_acquisition'; +GRANT EXECUTE ON PROCEDURE upsert_dc_grid_v2 TO 'ispyb_acquisition'; GRANT EXECUTE ON PROCEDURE update_dc_append_comments TO 'ispyb_acquisition'; GRANT EXECUTE ON PROCEDURE update_dc_position TO 'ispyb_acquisition'; diff --git a/schemas/ispyb/lookups.sql b/schemas/ispyb/lookups.sql index 1a3172dd..90cf0da6 100644 --- a/schemas/ispyb/lookups.sql +++ b/schemas/ispyb/lookups.sql @@ -10,7 +10,7 @@ /*!40111 SET @OLD_SQL_NOTES=@@SQL_NOTES, SQL_NOTES=0 */; /*!40000 ALTER TABLE `AdminVar` DISABLE KEYS */; -INSERT INTO `AdminVar` (`varId`, `name`, `value`) VALUES (4,'schemaVersion','2.0.0'); +INSERT INTO `AdminVar` (`varId`, `name`, `value`) VALUES (4,'schemaVersion','2.1.0'); /*!40000 ALTER TABLE `AdminVar` ENABLE KEYS */; /*!40000 ALTER TABLE `SchemaStatus` DISABLE KEYS */; @@ -227,7 +227,8 @@ INSERT INTO `SchemaStatus` (`schemaStatusId`, `scriptName`, `schemaStatus`, `rec (252,'2023_05_05_ParticleClassificationGroup_selected.sql','DONE','2023-05-05 14:25:42'), (253,'2023_05_09_Dewar_modify_comments.sql','DONE','2023-05-11 15:32:52'), (254,'2023_05_11_ParticleClassification_selected.sql','DONE','2023-05-11 15:32:52'), -(255,'2023_05_15_AdminVar_bump_version.sql','DONE','2023-05-15 09:59:49'); +(255,'2023_05_15_AdminVar_bump_version.sql','DONE','2023-05-15 09:59:49'), +(256,'2023_06_05_AdminVar_bump_version.sql','DONE','2023-06-05 15:13:35'); /*!40000 ALTER TABLE `SchemaStatus` ENABLE KEYS */; /*!40000 ALTER TABLE `ComponentType` DISABLE KEYS */; diff --git a/schemas/ispyb/routines.sql b/schemas/ispyb/routines.sql index 9e717131..87f61b16 100644 --- a/schemas/ispyb/routines.sql +++ b/schemas/ispyb/routines.sql @@ -130,7 +130,7 @@ DELIMITER ; /*!50003 SET character_set_results = utf8mb3 */ ; /*!50003 SET collation_connection = utf8mb3_general_ci */ ; DELIMITER ;; -CREATE FUNCTION `retrieve_proposal_title`(p_proposal_code varchar(5), p_proposal_number int) RETURNS varchar(255) CHARSET latin1 COLLATE latin1_swedish_ci +CREATE FUNCTION `retrieve_proposal_title`(p_proposal_code varchar(5), p_proposal_number int) RETURNS varchar(255) CHARSET latin1 READS SQL DATA BEGIN DECLARE ret_title varchar(255); @@ -155,7 +155,7 @@ DELIMITER ; /*!50003 SET character_set_results = utf8mb3 */ ; /*!50003 SET collation_connection = utf8mb3_general_ci */ ; DELIMITER ;; -CREATE FUNCTION `retrieve_proposal_title_v2`(p_proposalCode varchar(5), p_proposalNumber int) RETURNS varchar(255) CHARSET latin1 COLLATE latin1_swedish_ci +CREATE FUNCTION `retrieve_proposal_title_v2`(p_proposalCode varchar(5), p_proposalNumber int) RETURNS varchar(255) CHARSET latin1 READS SQL DATA COMMENT 'Retrieve the title for a given proposal code and number.' BEGIN @@ -206,7 +206,7 @@ DELIMITER ; /*!50003 SET character_set_results = utf8mb3 */ ; /*!50003 SET collation_connection = utf8mb3_general_ci */ ; DELIMITER ;; -CREATE FUNCTION `root_replace`(p_str varchar(255), p_oldroot varchar(255), p_newroot varchar(255)) RETURNS varchar(255) CHARSET latin1 COLLATE latin1_swedish_ci +CREATE FUNCTION `root_replace`(p_str varchar(255), p_oldroot varchar(255), p_newroot varchar(255)) RETURNS varchar(255) CHARSET latin1 COMMENT 'Returns a varchar where the old root p_oldroot (the leftmost part) of p_str has been replaced with a new root p_newroot' BEGIN DECLARE path_len smallint unsigned DEFAULT LENGTH(p_oldroot); @@ -9009,6 +9009,63 @@ DELIMITER ; /*!50003 SET character_set_results = @saved_cs_results */ ; /*!50003 SET collation_connection = @saved_col_connection */ ; /*!50003 SET @saved_sql_mode = @@sql_mode */ ; +/*!50003 SET sql_mode = 'STRICT_TRANS_TABLES,ERROR_FOR_DIVISION_BY_ZERO,NO_AUTO_CREATE_USER,NO_ENGINE_SUBSTITUTION' */ ; +/*!50003 DROP PROCEDURE IF EXISTS `upsert_dc_grid_v2` */; +/*!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 = utf8mb3 */ ; +/*!50003 SET character_set_results = utf8mb3 */ ; +/*!50003 SET collation_connection = utf8mb3_general_ci */ ; +DELIMITER ;; +CREATE PROCEDURE `upsert_dc_grid_v2`( + INOUT p_id int(11) unsigned, + p_dcId int(11) unsigned, + p_dxInMm double, + p_dyInMm double, + p_stepsX double, + p_stepsY double, + p_meshAngle double, + p_micronsPerPixelX float, + p_micronsPerPixelY float, + p_snapshotOffsetXPixel float, + p_snapshotOffsetYPixel float, + p_orientation enum('vertical','horizontal'), + p_snaked boolean +) + MODIFIES SQL DATA +BEGIN + IF p_dcId IS NOT NULL THEN + INSERT INTO GridInfo (gridInfoId, dataCollectionId, dx_mm, dy_mm, steps_x, steps_y, meshAngle, + micronsPerPixelX, micronsPerPixelY, snapshot_offsetXPixel, snapshot_offsetYPixel, + orientation, snaked) + VALUES (p_id, p_dcId, p_dxInMm, p_dyInMm, p_stepsX, p_stepsY, p_meshAngle, + p_micronsPerPixelX, p_micronsPerPixelY, p_snapshotOffsetXPixel, p_snapshotOffsetYPixel, + p_orientation, p_snaked) + ON DUPLICATE KEY UPDATE + dataCollectionId = IFNULL(p_dcId, dataCollectionId), + dx_mm = IFNULL(p_dxInMm, dx_mm), + dy_mm = IFNULL(p_dyInMm, dy_mm), + steps_x = IFNULL(p_stepsX, steps_x), + steps_y = IFNULL(p_stepsY, steps_y), + meshAngle = IFNULL(p_meshAngle, meshAngle), + micronsPerPixelX = IFNULL(p_micronsPerPixelX, micronsPerPixelX), + micronsPerPixelY = IFNULL(p_micronsPerPixelY, micronsPerPixelY), + snapshot_offsetXPixel = IFNULL(p_snapshotOffsetXPixel, snapshot_offsetXPixel), + snapshot_offsetYPixel = IFNULL(p_snapshotOffsetYPixel, snapshot_offsetYPixel), + orientation = IFNULL(p_orientation, orientation), + snaked = IFNULL(p_snaked, snaked); + IF LAST_INSERT_ID() <> 0 THEN + SET p_id = LAST_INSERT_ID(); + END IF; + 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 SET @saved_sql_mode = @@sql_mode */ ; /*!50003 SET sql_mode = '' */ ; /*!50003 DROP PROCEDURE IF EXISTS `upsert_dc_group` */; /*!50003 SET @saved_cs_client = @@character_set_client */ ; diff --git a/schemas/ispyb/stored_programs/sp_upsert_dc_grid_v2.sql b/schemas/ispyb/stored_programs/sp_upsert_dc_grid_v2.sql new file mode 100644 index 00000000..f1100abc --- /dev/null +++ b/schemas/ispyb/stored_programs/sp_upsert_dc_grid_v2.sql @@ -0,0 +1,48 @@ +-- Example call: +-- SET @id := NULL; +-- CALL upsert_dc_grid_v2(@id, 993677, 1.0, 2.0, 3, 4, 90, 10, 20, 30, 40, 'vertical', TRUE); + +DELIMITER ;; +CREATE OR REPLACE DEFINER=`ispyb_root`@`%` PROCEDURE `upsert_dc_grid_v2`( + INOUT p_id int(11) unsigned, + p_dcId int(11) unsigned, + p_dxInMm double, + p_dyInMm double, + p_stepsX double, + p_stepsY double, + p_meshAngle double, + p_micronsPerPixelX float, + p_micronsPerPixelY float, + p_snapshotOffsetXPixel float, + p_snapshotOffsetYPixel float, + p_orientation enum('vertical','horizontal'), + p_snaked boolean +) + MODIFIES SQL DATA +BEGIN + IF p_dcId IS NOT NULL THEN + INSERT INTO GridInfo (gridInfoId, dataCollectionId, dx_mm, dy_mm, steps_x, steps_y, meshAngle, + micronsPerPixelX, micronsPerPixelY, snapshot_offsetXPixel, snapshot_offsetYPixel, + orientation, snaked) + VALUES (p_id, p_dcId, p_dxInMm, p_dyInMm, p_stepsX, p_stepsY, p_meshAngle, + p_micronsPerPixelX, p_micronsPerPixelY, p_snapshotOffsetXPixel, p_snapshotOffsetYPixel, + p_orientation, p_snaked) + ON DUPLICATE KEY UPDATE + dataCollectionId = IFNULL(p_dcId, dataCollectionId), + dx_mm = IFNULL(p_dxInMm, dx_mm), + dy_mm = IFNULL(p_dyInMm, dy_mm), + steps_x = IFNULL(p_stepsX, steps_x), + steps_y = IFNULL(p_stepsY, steps_y), + meshAngle = IFNULL(p_meshAngle, meshAngle), + micronsPerPixelX = IFNULL(p_micronsPerPixelX, micronsPerPixelX), + micronsPerPixelY = IFNULL(p_micronsPerPixelY, micronsPerPixelY), + snapshot_offsetXPixel = IFNULL(p_snapshotOffsetXPixel, snapshot_offsetXPixel), + snapshot_offsetYPixel = IFNULL(p_snapshotOffsetYPixel, snapshot_offsetYPixel), + orientation = IFNULL(p_orientation, orientation), + snaked = IFNULL(p_snaked, snaked); + IF LAST_INSERT_ID() <> 0 THEN + SET p_id = LAST_INSERT_ID(); + END IF; + END IF; +END ;; +DELIMITER ; diff --git a/schemas/ispyb/updates/2023_06_05_AdminVar_bump_version.sql b/schemas/ispyb/updates/2023_06_05_AdminVar_bump_version.sql new file mode 100644 index 00000000..55eaedcb --- /dev/null +++ b/schemas/ispyb/updates/2023_06_05_AdminVar_bump_version.sql @@ -0,0 +1,5 @@ +INSERT IGNORE INTO SchemaStatus (scriptName, schemaStatus) VALUES ('2023_06_05_AdminVar_bump_version.sql', 'ONGOING'); + +UPDATE AdminVar SET `value` = '2.1.0' WHERE `name` = 'schemaVersion'; + +UPDATE SchemaStatus SET schemaStatus = 'DONE' WHERE scriptName = '2023_06_05_AdminVar_bump_version.sql';