MySQL 聚合函数里面提供了加,平均数,最小,最大等,但是没有提供乘法,我们这里来利用MYSQL现有的GROUP_CONCAT函数实现聚合乘法。
先创建一张示例表:
-
CREATE TABLE `tb_seq` (
-
`num` int(10) NOT NULL,
-
`seq_type` enum('yellow','green','red') NOT NULL
-
) ENGINE=InnoDB DEFAULT CHARSET=utf8;
插入示例数据:
-
insert into `tb_seq`(`num`,`seq_type`)
-
values (4,'green'),(1,'red'),(3,'green'),
-
(1,'red'),(8,'red'),(4,'yellow'),
-
(8,'red'),(7,'yellow'),(10,'red'),
-
(1,'red'),(1,'red'),(1,'yellow'),
-
(5,'green'),(9,'red'),(1,'yellow'),
-
(6,'yellow');
创建基于逗号分隔符的字符串乘法,前提是字符串逗号分隔的都是数字。
-
DELIMITER $$
-
-
-
USE `t_girl`$$
-
-
-
DROP FUNCTION IF EXISTS `func_multiple`$$
-
-
-
CREATE DEFINER=`root`@`localhost` FUNCTION `func_multiple`(
-
f_nums VARCHAR(1000)
-
) RETURNS DOUBLE(10,2)
-
BEGIN
-
-- Created by ytt 2014/10/21.
-
DECLARE result DOUBLE(10,2) DEFAULT 1;
-
DECLARE cnt,i INT DEFAULT 0;
-
-
SET cnt = CHAR_LENGTH(f_nums) - CHAR_LENGTH(REPLACE(f_nums,',','')) + 1;
-
-
WHILE i < cnt
-
DO
-
-- get multiple result.
-
SET result = result * REVERSE(SUBSTRING_INDEX(REVERSE(SUBSTRING_INDEX(f_nums,',',i+1)),',',1));
-
SET i = i + 1;
-
END WHILE;
-
SET result = ROUND(result,2);
-
RETURN result;
-
-
END$$
-
-
-
DELIMITER ;
好了,我们利用我创建的函数以及MYSQL自带的GROUP_CONCAT聚合函数就可以很方便的实现乘法了。
-
SELECT seq_type,func_multiple(GROUP_CONCAT(num ORDER BY num ASC SEPARATOR ',')) AS multiple_num FROM tb_seq WHERE 1 GROUP BY seq_type;
-
-
-
+----------+--------------+
-
| seq_type | multiple_num |
-
+----------+--------------+
-
| yellow | 168.00 |
-
| green | 60.00 |
-
| red | 5760.00 |
-
+----------+--------------+
-
3 rows in set (0.00 sec)
阅读(9659) | 评论(0) | 转发(0) |