目录
- month_days.sql:获取当前日期月份的天
- date_verify.sql:校验字符是否符合日期格式要求
- json_maker.sql: 从
sp
连接的字符串生成JSON - clear_num.sql:将字符串转成数值,清理非字符
- str_split.sql: 将字符串转json数组
目录
sp
连接的字符串生成JSON/* | |
test on MariaDB-10.5.10 | |
*/ | |
drop function if exists date_verify; | |
create function date_verify(date char(32), format char(30)) | |
returns tinyint | |
not deterministic | |
sql security definer | |
comment '判定输入是否日期要求' | |
begin | |
/*判定输入是否日期要求(返回值:1-正确 0-错误)*/ | |
declare v_date datetime; | |
-- declare v_format varchar(20) default '%Y-%m-%d %H:%i:%s'; -- 默认日期格式 | |
declare v_min_date datetime default '1900-01-01 00:00:00'; -- 最小的日期 | |
declare v_max_date datetime default '2099-12-31 23:59:59'; -- 最大的日期 | |
select str_to_date(date,format) into v_date; | |
-- 不符合日期格式,无法转datetime | |
if v_date is null then | |
return 0; | |
end if; | |
-- 小于最小值 | |
if v_min_date is not null then | |
if v_date < v_min_date then | |
return 0; | |
end if; | |
end if; | |
-- 大于最小值 | |
if v_max_date is not null then | |
if v_date > v_max_date then | |
return 0; | |
end if; | |
end if; | |
return 1; | |
end; |
/* | |
test on MariaDB-10.5.10 | |
eg: | |
select json_maker('A^B^C', '1^2^3','^'); | |
result: | |
{"A":"1","B":"2","C":"3"} | |
*/ | |
DROP FUNCTION IF EXISTS json_maker; | |
CREATE FUNCTION `json_maker`(FIELDS TEXT, MY_VALUES TEXT, SP varchar(10)) RETURNS text CHARSET utf8 | |
BEGIN | |
/* Generate JSON from string concatenated by `SP` | |
params: | |
Make sure the keys and values are in the same order ~ | |
FIELDS: json's keys | |
MY_VALUES: json's values | |
SP: separator for `FIELDS` and `MY_VALUES` | |
*/ | |
DECLARE JSON_STR TEXT; | |
DECLARE I INT DEFAULT 1; | |
DECLARE KEY_NAME_TMP VARCHAR(100); | |
DECLARE VAL_NAME_TMP VARCHAR(500); | |
DECLARE KEY_VAL_TMP VARCHAR(1000); | |
-- get fields number | |
SELECT LENGTH(FIELDS)-LENGTH(REPLACE(FIELDS,SP,'' )) + 1 INTO @FIELDS_LEN; | |
-- SELECT LENGTH(MY_VALUES)-LENGTH(REPLACE(MY_VALUES,SP,'' )) + 1 INTO @MY_VALUES_LEN; | |
WHILE I <= @FIELDS_LEN DO | |
SET KEY_NAME_TMP = SUBSTRING_INDEX(SUBSTRING_INDEX(FIELDS, SP,I),SP,-1); | |
SET VAL_NAME_TMP = SUBSTRING_INDEX(SUBSTRING_INDEX(MY_VALUES, SP,I),SP,-1); | |
SET KEY_VAL_TMP = CONCAT(JSON_QUOTE(KEY_NAME_TMP), ':', JSON_QUOTE(VAL_NAME_TMP)); | |
SET JSON_STR = CONCAT_WS(',', JSON_STR, KEY_VAL_TMP); | |
SET I = I + 1; | |
end while; | |
SET JSON_STR = CONCAT('{', JSON_STR, '}'); | |
RETURN JSON_STR; | |
END; |
/* | |
test on MariaDB-10.5.10 | |
*/ | |
drop function if exists month_days; | |
create function month_days(date datetime) returns tinyint comment '获取当前日期月份的天数' | |
begin | |
return dayofmonth(last_day(date)); | |
end; |
/* test on MariaDB-10.5.10
eg:
select clear_num('dfsa1&23,98f%');
result:
123.98
*/
drop function if exists clear_num;
CREATE FUNCTION clear_num
(V_NUM varchar(100)) RETURNS DECIMAL(18,2)
BEGIN
/*
get a clear number, conver string to number.
',' & ',' & '.' Is treated as a numeric decimal point. Modify it at line 22 if necessary
*/ DECLARE V_RESULT TEXT; DECLARE I INT DEFAULT 1;
-- get char number of V_NUM
SELECT char_length(V_NUM) INTO @V_LEN;
WHILE I <= @V_LEN DO
SELECT right(left(V_NUM, I), 1) INTO @V_CHAR;
IF @V_CHAR REGEXP('^[,,.]$') > 0 THEN
SET V_RESULT = CONCAT_WS('', V_RESULT, '.');
ELSEIF @V_CHAR REGEXP('^[0-9]$') > 0 THEN
SET V_RESULT = CONCAT_WS('', V_RESULT, @V_CHAR);
END IF;
SET I = I + 1;
end while;
RETURN V_RESULT + 0;
END $$;
/* | |
test on MariaDB-10.5.10 | |
*/ | |
drop function if exists str_split; | |
create function str_split(v_str varchar(50), v_sp varchar(10)) returns json | |
begin | |
/* | |
String to JSON array by the separator | |
eg. | |
select str_split('www.baidu.com','.'); | |
return: | |
'["www", "baidu", "com"]' | |
*/ | |
declare v_len int; | |
declare i int default 1; | |
declare v_json_array json default '[]'; | |
set v_len = length(v_str) - length(replace(v_str, v_sp, '')) + 1; | |
while i <= v_len do | |
set v_json_array = json_array_insert(v_json_array, concat('$[', i-1, ']'), substring_index(substring_index(v_str, v_sp, i), v_sp, -1)); | |
set i = i + 1; | |
end while; | |
return v_json_array; | |
end; |