Skip to content

Improve Function performance #189

New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Open
wants to merge 5 commits into
base: main
Choose a base branch
from
Open
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
Original file line number Diff line number Diff line change
Expand Up @@ -2,32 +2,33 @@ DROP FUNCTION IF EXISTS fn_mamba_get_obs_value_column;

DELIMITER //

CREATE FUNCTION fn_mamba_get_obs_value_column(conceptDatatype VARCHAR(20)) RETURNS VARCHAR(20)
CREATE FUNCTION fn_mamba_get_obs_value_column(conceptDatatype VARCHAR(20))
RETURNS VARCHAR(20)
DETERMINISTIC
NO SQL
COMMENT 'Determines the appropriate obs value column based on concept datatype. Returns column name as: obs_value_text, obs_value_boolean, obs_value_datetime, or obs_value_numeric.'

BEGIN
DECLARE obsValueColumn VARCHAR(20);

IF conceptDatatype = 'Text' THEN
SET obsValueColumn = 'obs_value_text';
CASE LOWER(conceptDatatype)

WHEN 'text' THEN SET obsValueColumn = 'obs_value_text'; -- Free text values

WHEN 'coded' THEN SET obsValueColumn = 'obs_value_text'; -- Coded concept IDs stored as text

ELSEIF conceptDatatype = 'Coded'
OR conceptDatatype = 'N/A' THEN
SET obsValueColumn = 'obs_value_text';
WHEN 'n/a' THEN SET obsValueColumn = 'obs_value_text'; -- Handle unspecified/not-applicable types

ELSEIF conceptDatatype = 'Boolean' THEN
SET obsValueColumn = 'obs_value_boolean';
WHEN 'boolean' THEN SET obsValueColumn = 'obs_value_boolean'; -- True/false values

ELSEIF conceptDatatype = 'Date'
OR conceptDatatype = 'Datetime' THEN
SET obsValueColumn = 'obs_value_datetime';
WHEN 'date' THEN SET obsValueColumn = 'obs_value_datetime'; -- Date/datetime values

ELSEIF conceptDatatype = 'Numeric' THEN
SET obsValueColumn = 'obs_value_numeric';
WHEN 'datetime' THEN SET obsValueColumn = 'obs_value_datetime'; -- Explicit datetime handling

ELSE
SET obsValueColumn = 'obs_value_text';
WHEN 'numeric' THEN SET obsValueColumn = 'obs_value_numeric'; -- Numeric measurements

END IF;
ELSE SET obsValueColumn = 'obs_value_text';
END CASE;

RETURN (obsValueColumn);
END //
Expand Down
Original file line number Diff line number Diff line change
@@ -0,0 +1,21 @@
DROP FUNCTION IF EXISTS fn_mamba_is_mysql8_or_higher;

DELIMITER //

CREATE FUNCTION fn_mamba_is_mysql8_or_higher()
RETURNS BOOLEAN
DETERMINISTIC
READS SQL DATA
COMMENT 'Returns TRUE if MySQL version is 8.0 or higher, FALSE otherwise'

BEGIN
DECLARE mysql_version VARCHAR(20);

-- Get MySQL major version number
SET mysql_version = SUBSTRING_INDEX(VERSION(), '.', 1);

-- Return TRUE if version is 8 or higher
RETURN CAST(mysql_version AS UNSIGNED) >= 8;
END //

DELIMITER ;
Original file line number Diff line number Diff line change
@@ -1,33 +1,61 @@
DROP FUNCTION IF EXISTS fn_mamba_json_array_length;

DELIMITER //

CREATE FUNCTION fn_mamba_json_array_length(json_array TEXT) RETURNS INT
CREATE FUNCTION fn_mamba_json_array_length(json_array TEXT)
RETURNS INT
DETERMINISTIC
READS SQL DATA
COMMENT 'Returns the number of objects in a JSON array'

BEGIN
DECLARE array_length INT DEFAULT 0;
DECLARE current_pos INT DEFAULT 1;
DECLARE char_val CHAR(1);
DECLARE brace_counter INT DEFAULT 0;

-- Handle NULL input
IF json_array IS NULL THEN
RETURN 0;
END IF;

-- Iterate over the string to count the number of objects based on commas and curly braces
WHILE current_pos <= CHAR_LENGTH(json_array) DO
SET char_val = SUBSTRING(json_array, current_pos, 1);

-- Check for the start of an object
IF char_val = '{' THEN
SET array_length = array_length + 1;

-- Move current_pos to the end of this object
SET current_pos = LOCATE('}', json_array, current_pos) + 1;
-- Use native JSON functions for MySQL 8.0+
IF fn_mamba_is_mysql8_or_higher() THEN
-- Check if input is a valid JSON array
IF JSON_VALID(json_array) AND JSON_TYPE(json_array) = 'ARRAY' THEN
RETURN JSON_LENGTH(json_array);
ELSE
SET current_pos = current_pos + 1;
RETURN 0;
END IF;
ELSE
-- Fallback for MySQL 5.7 and earlier - manual counting

-- Basic validation - check if it looks like an array
IF NOT (json_array LIKE '[%]') THEN
RETURN 0;
END IF;
END WHILE;

RETURN array_length;
-- Iterate over the string to count the number of objects based on commas and curly braces
WHILE current_pos <= CHAR_LENGTH(json_array)
DO
SET char_val = SUBSTRING(json_array, current_pos, 1);

-- Check for the start of an object
IF char_val = '{' THEN
-- Only count top-level objects
IF brace_counter = 0 THEN
SET array_length = array_length + 1;
END IF;
SET brace_counter = brace_counter + 1;
ELSEIF char_val = '}' THEN
SET brace_counter = brace_counter - 1;
END IF;

SET current_pos = current_pos + 1;
END WHILE;

RETURN array_length;
END IF;
END //

DELIMITER ;
Original file line number Diff line number Diff line change
@@ -1,36 +1,63 @@
DROP FUNCTION IF EXISTS fn_mamba_json_extract;

DELIMITER //

CREATE FUNCTION fn_mamba_json_extract(json TEXT, key_name VARCHAR(255)) RETURNS VARCHAR(255)
CREATE FUNCTION fn_mamba_json_extract(json TEXT, key_name VARCHAR(255))
RETURNS VARCHAR(255)
DETERMINISTIC
BEGIN
DECLARE start_index INT;
DECLARE end_index INT;
DECLARE key_length INT;
DECLARE key_index INT;
READS SQL DATA
COMMENT 'Extracts a value from a JSON string by key name'

SET key_name = CONCAT( key_name, '":');
SET key_length = CHAR_LENGTH(key_name);
SET key_index = LOCATE(key_name, json);
BEGIN
DECLARE start_index INT;
DECLARE end_index INT;
DECLARE key_length INT;
DECLARE key_index INT;

IF key_index = 0 THEN
-- Handle NULL inputs
IF json IS NULL OR key_name IS NULL THEN
RETURN NULL;
END IF;

SET start_index = key_index + key_length;
-- Use native JSON functions for MySQL 8.0+
IF fn_mamba_is_mysql8_or_higher() THEN
-- Use built-in JSON functions for better performance and accuracy
RETURN JSON_EXTRACT(json, CONCAT('$.', key_name));
ELSE
-- Fallback for MySQL 5.7 and earlier - manual JSON parsing

-- Basic validation - check if it looks like an object
IF NOT (json LIKE '{%}') THEN
RETURN NULL;
END IF;

-- Add the key structure to search for in the JSON string
SET key_name = CONCAT('"', key_name, '":');
SET key_length = CHAR_LENGTH(key_name);
SET key_index = LOCATE(key_name, json);

CASE
WHEN SUBSTRING(json, start_index, 1) = '"' THEN
SET start_index = start_index + 1;
SET end_index = LOCATE('"', json, start_index);
ELSE
SET end_index = LOCATE(',', json, start_index);
IF end_index = 0 THEN
SET end_index = LOCATE('}', json, start_index);
END IF;
END CASE;
IF key_index = 0 THEN
RETURN NULL;
END IF;

RETURN SUBSTRING(json, start_index, end_index - start_index);
SET start_index = key_index + key_length;

CASE
WHEN SUBSTRING(json, start_index, 1) = '"' THEN SET start_index = start_index + 1;
SET end_index = LOCATE('"', json, start_index);
ELSE SET end_index = LOCATE(',', json, start_index);
IF end_index = 0 THEN
SET end_index = LOCATE('}', json, start_index);
END IF;
END CASE;

-- Handle case where end marker wasn't found
IF end_index = 0 THEN
RETURN NULL;
END IF;

RETURN SUBSTRING(json, start_index, end_index - start_index);
END IF;
END //

DELIMITER ;
Original file line number Diff line number Diff line change
@@ -1,47 +1,87 @@
DROP FUNCTION IF EXISTS fn_mamba_json_extract_array;

DELIMITER //

CREATE FUNCTION fn_mamba_json_extract_array(json TEXT, key_name VARCHAR(255)) RETURNS TEXT
CREATE FUNCTION fn_mamba_json_extract_array(json TEXT, key_name VARCHAR(255))
RETURNS TEXT
DETERMINISTIC
BEGIN
DECLARE start_index INT;
DECLARE end_index INT;
DECLARE array_text TEXT;
READS SQL DATA
COMMENT 'Extracts an array from a JSON string by key name'

SET key_name = CONCAT('"', key_name, '":');
SET start_index = LOCATE(key_name, json);
BEGIN
DECLARE start_index INT;
DECLARE end_index INT;
DECLARE array_text TEXT;
DECLARE bracket_counter INT;

IF start_index = 0 THEN
-- Handle NULL inputs
IF json IS NULL OR key_name IS NULL THEN
RETURN NULL;
END IF;

SET start_index = start_index + CHAR_LENGTH(key_name);
-- Use native JSON functions for MySQL 8.0+
IF fn_mamba_is_mysql8_or_higher() THEN
-- Use built-in JSON functions for better performance and accuracy
-- Check if the extracted value is an array
IF JSON_VALID(json) AND JSON_TYPE(JSON_EXTRACT(json, CONCAT('$.', key_name))) = 'ARRAY' THEN
-- Return the array without the surrounding quotes
RETURN JSON_EXTRACT(json, CONCAT('$.', key_name));
ELSE
RETURN NULL;
END IF;
ELSE
-- Fallback for MySQL 5.7 and earlier - manual JSON parsing

IF SUBSTRING(json, start_index, 1) != '[' THEN
RETURN NULL;
END IF;
-- Basic validation - check if it looks like an object
IF NOT (json LIKE '{%}') THEN
RETURN NULL;
END IF;

SET start_index = start_index + 1; -- Start after the '['
SET end_index = start_index;

-- Loop to find the matching closing bracket for the array
SET @bracket_counter = 1;
WHILE @bracket_counter > 0 AND end_index <= CHAR_LENGTH(json) DO
SET end_index = end_index + 1;
IF SUBSTRING(json, end_index, 1) = '[' THEN
SET @bracket_counter = @bracket_counter + 1;
ELSEIF SUBSTRING(json, end_index, 1) = ']' THEN
SET @bracket_counter = @bracket_counter - 1;
-- Add the key structure to search for in the JSON string
SET key_name = CONCAT('"', key_name, '":');
SET start_index = LOCATE(key_name, json);

IF start_index = 0 THEN
RETURN NULL;
END IF;
END WHILE;

IF @bracket_counter != 0 THEN
RETURN NULL; -- The brackets are not balanced, return NULL
END IF;
SET start_index = start_index + CHAR_LENGTH(key_name);

SET array_text = SUBSTRING(json, start_index, end_index - start_index);
-- Skip any whitespace
WHILE SUBSTRING(json, start_index, 1) IN (' ', '\t', '\n', '\r')
DO
SET start_index = start_index + 1;
END WHILE;

RETURN array_text;
-- Check if we're looking at an array
IF SUBSTRING(json, start_index, 1) != '[' THEN
RETURN NULL;
END IF;

-- Find the matching closing bracket
SET start_index = start_index; -- Keep the opening bracket
SET end_index = start_index;
SET bracket_counter = 1;

WHILE bracket_counter > 0 AND end_index < CHAR_LENGTH(json)
DO
SET end_index = end_index + 1;
IF SUBSTRING(json, end_index, 1) = '[' THEN
SET bracket_counter = bracket_counter + 1;
ELSEIF SUBSTRING(json, end_index, 1) = ']' THEN
SET bracket_counter = bracket_counter - 1;
END IF;
END WHILE;

IF bracket_counter != 0 THEN
RETURN NULL; -- The brackets are not balanced, return NULL
END IF;

-- Include the closing bracket in the result
SET array_text = SUBSTRING(json, start_index, end_index - start_index + 1);

RETURN array_text;
END IF;
END //

DELIMITER ;
Loading