阿里云serverless版本msyql5.7调用函数抛异常 3061 - User variable name '' is illegal
之前是自建的mysql5.6,当升级到阿里云serverless的msyql5.7的时候发现生成订单号的函数抛异常。
3061 - User variable name '' is illegal
call generate_orderNo('F',14,@)
这个版本需要@后面增加函数出参数变量名
call generate_orderNo('F',14,@newOrderNo)
下面是生成订单号函数:
DROP PROCEDURE IF EXISTS `generate_orderNo`;
delimiter ;;
CREATE PROCEDURE `generate_orderNo`(IN orderNamePre CHAR(4),
IN num INT,
OUT newOrderNo VARCHAR (25))
BEGIN
-- 订单变化的值
DECLARE orderNameValue INT ;
-- 更新行数
DECLARE updateRow INT ;
-- 当前日期,有可能包含时分秒
DECLARE currentTime DATETIME ;
-- 订单号
DECLARE orderCode VARCHAR (64) ;
DECLARE orderNum INT DEFAULT 5; -- 订单变化的值
-- 异常处理
DECLARE CONTINUE HANDLER FOR 1062
SET currentTime = NOW() ;
-- 获得订单号
SELECT
IFNULL(gs.ordervalue, 0) INTO orderNameValue
FROM
generate_serialno gs
WHERE id = 1 ;
SET currentTime = NOW() ;
-- 打开自动提交
SET autocommit = 1 ;
IF TRUE -- 如果true插入一条数据
THEN
INSERT INTO generate_serialno (id, ordervalue, ordertime)
VALUES
(1, 1, currentTime) ;
END IF ; -- 否则更改订单号
UPDATE
generate_serialno obj
SET
obj.ordervalue =
CASE -- 订单变化的值如果今天大于昨天从1开始,否则再原来的基础上加1
WHEN TO_DAYS(currentTime) > TO_DAYS(obj.ordertime)
THEN 1
ELSE orderNameValue + 1
END,
obj.ordertime = currentTime
WHERE ( -- 订单变化的值
obj.id = 1
AND obj.ordervalue = orderNameValue
) ;
SET updateRow = ROW_COUNT() ;
WHILE
! updateRow = 1 DO -- 如果更改的行数不等于1
SELECT -- 获得当前的订单变化值
IFNULL(gs.ordervalue, 0) INTO orderNameValue
FROM
generate_serialno gs
WHERE id = 1 ;
UPDATE
generate_serialno obj
SET
obj.ordervalue =
CASE
WHEN TO_DAYS(currentTime) > TO_DAYS(obj.ordertime)
THEN 1
ELSE orderNameValue + 1
END,
obj.ordertime = currentTime
WHERE (-- 只有订单变化值和id都相等的情况下才能更改,更具行锁的机制
obj.id = 1
AND obj.ordervalue = orderNameValue -- 注意!!!!
) ;
SET updateRow = ROW_COUNT() ;
END WHILE ;
IF num = 8
THEN -- 根据年月日生成订单编号,订单编号形式:前缀+年月日+流水号,如:SH2013011000002
SELECT
CONCAT(
orderNamePre,
DATE_FORMAT(currentTime, '%Y%m%d'),
LPAD(orderNameValue, orderNum, '0')
) INTO orderCode ;
ELSEIF num = 14
THEN -- 根据年月日时分秒生成订单编号,订单编号形式:前缀+年月日时分秒+流水号,如:SH2013011010050700001,个人不推荐使用这种方法生成流水号
SELECT
CONCAT(
orderNamePre,
DATE_FORMAT(currentTime, '%Y%m%d%H%i%s'),
LPAD(orderNameValue, orderNum, '0')
) INTO orderCode ;
ELSE -- 根据年月日时分生成订单编号,订单形式:前缀+年月日时分+流水号,如:SH20130110100900005
SELECT
CONCAT(
orderNamePre,
DATE_FORMAT(currentTime, '%Y%m%d%H%i'),
LPAD(orderNameValue, orderNum, '0')
) INTO orderCode ;
END IF ;
SELECT
orderCode ;
END
;;
delimiter ;
以及对应的mysql表结构:
DROP TABLE IF EXISTS `generate_serialno`;
CREATE TABLE `generate_serialno` (
`id` int(11) NOT NULL,
`ordervalue` varchar(255) CHARACTER SET utf8 COLLATE utf8_unicode_ci NULL DEFAULT NULL,
`ordertime` datetime(0) NULL DEFAULT NULL,
PRIMARY KEY (`id`) USING BTREE
) ENGINE = InnoDB CHARACTER SET = utf8 COLLATE = utf8_unicode_ci ROW_FORMAT = Compact;
-- ----------------------------
-- Records of generate_serialno
-- ----------------------------
INSERT INTO `generate_serialno` VALUES (1, '1', '2022-12-31 14:10:56');
版权声明:若无特殊注明,本文皆为《菜鸟站长》原创,转载请保留文章出处。
本文链接:阿里云serverless版本msyql5.7调用函数抛异常 3061 - User variable name '' is illegal - http://wlphp.com/?post=387