栏目说明[魔法棒挥动]
「Quick BI使用案例」系列短文都来源于用户遇到的真实问题。
文章聚焦使用过程中的高频误区与使用技巧,希望能帮助您更充分地发挥产品价值。
问题背景[问号]
某用户需要在仪表板中展示基于人员维度的指定时间段订单分组排序的序号。例如常见的货物运输场景,需要筛选指定日期范围后,展示各个司机在指定日期范围内累计第1单,第2单,第N单等。
解决方案[进度: 未开始]
方案一. 创建自定义SQL数据集,在明细表中展示订单序号。
Step1. 应用场景数据构建如下(数据源是MySQL 8.0),创建表并插入数据:
CREATE TABLE tbl_sales_info( order_id INT NOT NULL AUTO_INCREMENT comment '订单编号', report_date DATETIME comment '订单日期', driver_name CHAR(40) comment '司机姓名', order_level CHAR(40) comment '订单等级', shipping_type CHAR(40) comment '运输方式', area CHAR(40) comment '区域', province CHAR(40) comment '省份', city CHAR(40) comment '城市', product_type CHAR(40) comment '产品类型', product_sub_type CHAR(40) comment '产品小类', product_name CHAR(100) comment '产品名称', product_box CHAR(40) comment '产品包箱', shipping_date DATETIME comment '运输日期', order_number int comment '订单数量', order_amt float comment '订单金额', back_point float comment '折扣点', profit_amt float comment '利润金额', shipping_cost float comment '运输成本', payment_date DATETIME comment '付款日期', PRIMARY KEY(order_id)) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_0900_ai_ci; INSERT INTO tbl_sales_info(report_date,driver_name,order_level,shipping_type,area,province,city,product_type,product_sub_type,product_name,product_box,shipping_date,order_number,order_amt,back_point,profit_amt,shipping_cost,payment_date) VALUES(DATE_SUB(now(), INTERVAL 1 day),'明哲','其他','空运','华东','安徽省','合肥市','办公用品','电脑耗材','赫沃姆','打包纸袋',DATE_SUB(now(), INTERVAL 1 day),FLOOR(RAND()*100),RAND()*100,RAND()*100,RAND()*100-50,RAND()*100,DATE_SUB(now(), INTERVAL 1 day)); INSERT INTO tbl_sales_info(report_date,driver_name,order_level,shipping_type,area,province,city,product_type,product_sub_type,product_name,product_box,shipping_date,order_number,order_amt,back_point,profit_amt,shipping_cost,payment_date) VALUES(DATE_SUB(now(), INTERVAL 6 day),'明哲','其他','空运','华东','安徽省','合肥市','办公用品','电脑耗材','赫沃姆','打包纸袋',DATE_SUB(now(), INTERVAL 6 day),FLOOR(RAND()*100),RAND()*100,RAND()*100,RAND()*100-50,RAND()*100,DATE_SUB(now(), INTERVAL 6 day)); INSERT INTO tbl_sales_info(report_date,driver_name,order_level,shipping_type,area,province,city,product_type,product_sub_type,product_name,product_box,shipping_date,order_number,order_amt,back_point,profit_amt,shipping_cost,payment_date) VALUES(DATE_SUB(now(), INTERVAL 11 day),'明哲','其他','空运','华东','安徽省','合肥市','办公用品','电脑耗材','赫沃姆','打包纸袋',DATE_SUB(now(), INTERVAL 11 day),FLOOR(RAND()*100),RAND()*100,RAND()*100,RAND()*100-50,RAND()*100,DATE_SUB(now(), INTERVAL 11 day)); INSERT INTO tbl_sales_info(report_date,driver_name,order_level,shipping_type,area,province,city,product_type,product_sub_type,product_name,product_box,shipping_date,order_number,order_amt,back_point,profit_amt,shipping_cost,payment_date) VALUES(DATE_SUB(now(), INTERVAL 31 day),'明哲','其他','空运','华东','安徽省','合肥市','办公用品','电脑耗材','赫沃姆','打包纸袋',DATE_SUB(now(), INTERVAL 31 day),FLOOR(RAND()*100),RAND()*100,RAND()*100,RAND()*100-50,RAND()*100,DATE_SUB(now(), INTERVAL 31 day)); INSERT INTO tbl_sales_info(report_date,driver_name,order_level,shipping_type,area,province,city,product_type,product_sub_type,product_name,product_box,shipping_date,order_number,order_amt,back_point,profit_amt,shipping_cost,payment_date) VALUES(DATE_SUB(now(), INTERVAL 36 day),'明哲','其他','空运','华东','安徽省','合肥市','办公用品','电脑耗材','赫沃姆','打包纸袋',DATE_SUB(now(), INTERVAL 36 day),FLOOR(RAND()*100),RAND()*100,RAND()*100,RAND()*100-50,RAND()*100,DATE_SUB(now(), INTERVAL 36 day)); INSERT INTO tbl_sales_info(report_date,driver_name,order_level,shipping_type,area,province,city,product_type,product_sub_type,product_name,product_box,shipping_date,order_number,order_amt,back_point,profit_amt,shipping_cost,payment_date) VALUES(DATE_SUB(now(), INTERVAL 65 day),'明哲','其他','空运','华东','安徽省','合肥市','办公用品','电脑耗材','赫沃姆','打包纸袋',DATE_SUB(now(), INTERVAL 65 day),FLOOR(RAND()*100),RAND()*100,RAND()*100,RAND()*100-50,RAND()*100,DATE_SUB(now(), INTERVAL 65 day)); INSERT INTO tbl_sales_info(report_date,driver_name,order_level,shipping_type,area,province,city,product_type,product_sub_type,product_name,product_box,shipping_date,order_number,order_amt,back_point,profit_amt,shipping_cost,payment_date) VALUES(DATE_SUB(now(), INTERVAL 74 day),'明哲','其他','空运','华东','安徽省','合肥市','办公用品','电脑耗材','赫沃姆','打包纸袋',DATE_SUB(now(), INTERVAL 74 day),FLOOR(RAND()*100),RAND()*100,RAND()*100,RAND()*100-50,RAND()*100,DATE_SUB(now(), INTERVAL 74 day)); INSERT INTO tbl_sales_info(report_date,driver_name,order_level,shipping_type,area,province,city,product_type,product_sub_type,product_name,product_box,shipping_date,order_number,order_amt,back_point,profit_amt,shipping_cost,payment_date) VALUES(DATE_SUB(now(), INTERVAL 78 day),'明哲','其他','空运','华东','安徽省','合肥市','办公用品','电脑耗材','赫沃姆','打包纸袋',DATE_SUB(now(), INTERVAL 78 day),FLOOR(RAND()*100),RAND()*100,RAND()*100,RAND()*100-50,RAND()*100,DATE_SUB(now(), INTERVAL 78 day)); INSERT INTO tbl_sales_info(report_date,driver_name,order_level,shipping_type,area,province,city,product_type,product_sub_type,product_name,product_box,shipping_date,order_number,order_amt,back_point,profit_amt,shipping_cost,payment_date) VALUES(DATE_SUB(now(), INTERVAL 1 day),'子轩','其他','空运','华东','安徽省','合肥市','办公用品','电脑耗材','赫沃姆','打包纸袋',DATE_SUB(now(), INTERVAL 1 day),FLOOR(RAND()*100),RAND()*100,RAND()*100,RAND()*100-50,RAND()*100,DATE_SUB(now(), INTERVAL 1 day)); INSERT INTO tbl_sales_info(report_date,driver_name,order_level,shipping_type,area,province,city,product_type,product_sub_type,product_name,product_box,shipping_date,order_number,order_amt,back_point,profit_amt,shipping_cost,payment_date) VALUES(DATE_SUB(now(), INTERVAL 6 day),'子轩','其他','空运','华东','安徽省','合肥市','办公用品','电脑耗材','赫沃姆','打包纸袋',DATE_SUB(now(), INTERVAL 6 day),FLOOR(RAND()*100),RAND()*100,RAND()*100,RAND()*100-50,RAND()*100,DATE_SUB(now(), INTERVAL 6 day)); INSERT INTO tbl_sales_info(report_date,driver_name,order_level,shipping_type,area,province,city,product_type,product_sub_type,product_name,product_box,shipping_date,order_number,order_amt,back_point,profit_amt,shipping_cost,payment_date) VALUES(DATE_SUB(now(), INTERVAL 11 day),'子轩','其他','空运','华东','安徽省','合肥市','办公用品','电脑耗材','赫沃姆','打包纸袋',DATE_SUB(now(), INTERVAL 11 day),FLOOR(RAND()*100),RAND()*100,RAND()*100,RAND()*100-50,RAND()*100,DATE_SUB(now(), INTERVAL 11 day)); INSERT INTO tbl_sales_info(report_date,driver_name,order_level,shipping_type,area,province,city,product_type,product_sub_type,product_name,product_box,shipping_date,order_number,order_amt,back_point,profit_amt,shipping_cost,payment_date) VALUES(DATE_SUB(now(), INTERVAL 31 day),'子轩','其他','空运','华东','安徽省','合肥市','办公用品','电脑耗材','赫沃姆','打包纸袋',DATE_SUB(now(), INTERVAL 31 day),FLOOR(RAND()*100),RAND()*100,RAND()*100,RAND()*100-50,RAND()*100,DATE_SUB(now(), INTERVAL 31 day)); INSERT INTO tbl_sales_info(report_date,driver_name,order_level,shipping_type,area,province,city,product_type,product_sub_type,product_name,product_box,shipping_date,order_number,order_amt,back_point,profit_amt,shipping_cost,payment_date) VALUES(DATE_SUB(now(), INTERVAL 36 day),'子轩','其他','空运','华东','安徽省','合肥市','办公用品','电脑耗材','赫沃姆','打包纸袋',DATE_SUB(now(), INTERVAL 36 day),FLOOR(RAND()*100),RAND()*100,RAND()*100,RAND()*100-50,RAND()*100,DATE_SUB(now(), INTERVAL 36 day)); INSERT INTO tbl_sales_info(report_date,driver_name,order_level,shipping_type,area,province,city,product_type,product_sub_type,product_name,product_box,shipping_date,order_number,order_amt,back_point,profit_amt,shipping_cost,payment_date) VALUES(DATE_SUB(now(), INTERVAL 65 day),'子轩','其他','空运','华东','安徽省','合肥市','办公用品','电脑耗材','赫沃姆','打包纸袋',DATE_SUB(now(), INTERVAL 65 day),FLOOR(RAND()*100),RAND()*100,RAND()*100,RAND()*100-50,RAND()*100,DATE_SUB(now(), INTERVAL 65 day)); INSERT INTO tbl_sales_info(report_date,driver_name,order_level,shipping_type,area,province,city,product_type,product_sub_type,product_name,product_box,shipping_date,order_number,order_amt,back_point,profit_amt,shipping_cost,payment_date) VALUES(DATE_SUB(now(), INTERVAL 74 day),'子轩','其他','空运','华东','安徽省','合肥市','办公用品','电脑耗材','赫沃姆','打包纸袋',DATE_SUB(now(), INTERVAL 74 day),FLOOR(RAND()*100),RAND()*100,RAND()*100,RAND()*100-50,RAND()*100,DATE_SUB(now(), INTERVAL 74 day)); INSERT INTO tbl_sales_info(report_date,driver_name,order_level,shipping_type,area,province,city,product_type,product_sub_type,product_name,product_box,shipping_date,order_number,order_amt,back_point,profit_amt,shipping_cost,payment_date) VALUES(DATE_SUB(now(), INTERVAL 78 day),'子轩','其他','空运','华东','安徽省','合肥市','办公用品','电脑耗材','赫沃姆','打包纸袋',DATE_SUB(now(), INTERVAL 78 day),FLOOR(RAND()*100),RAND()*100,RAND()*100,RAND()*100-50,RAND()*100,DATE_SUB(now(), INTERVAL 78 day));
插入数据后,表tbl_sales_info中数据如下:
Step2. 创建自定义SQL数据集,在自定义SQL数据集中通过ROW_NUMBER() OVER和值占位符实现。
ROW_NUMBER() OVER 是 MYSQL 中的开窗函数,用于为查询结果集的每一行分配一个唯一的连续序号,常用于分组排序、数据去重和分页等场景。其核心语法为:
ROW_NUMBER() OVER (PARTITION BY 分组列 ORDER BY 排序列)
其中 PARTITION BY 用于分组,ORDER BY 用于组内排序,若省略 PARTITION BY 则对整个结果集排序。
Quick BI中值占位符可通过仪表板上的查询控件传入日期范围,进行筛选。当占位符是日期时,需要选择具体的日期格式,来控制传入值的格式。
占位符具体格式如下:
'$val{占位符名}'
通过ROW_NUMBER() OVER和值占位符实现的完整SQL代码如下:
SELECT order_id,report_date,driver_name,profit_amt,order_amt,ROW_NUMBER() OVER(PARTITION by driver_name ORDER BY report_date ASC) RN from (select * from tbl_sales_info WHERE report_date > '$val{report_date_ph.get(0)}' AND report_date < '$val{report_date_ph.get(1)}') b
其中ROW_NUMBER() OVER中根据driver_name分组,根据report_date进行排序。占位符变量名是report_date_ph,其中'$val{report_date_ph.get(0)}' 表示获取日期范围查询控件起始日期,'$val{report_date_ph.get(1)}'表示 获取日期范围控件结束日期。占位符具体设置如下:
Step3. 仪表板中创建明细表,字段配置如下:
查询控件配置如下:
Step4. 在明细表中展示效果如下:
查询10月的订单,RN列显示该订单是对应司机在10月份按照时序排列的订单序号(从1开始),如下图所示:
查询11月的订单,RN列显示该订单是对应司机在11月份按照时序排列的订单序号(从1开始),如下图所示:
方案二. 通过物理表建数据集,在交叉表展示订单序号。
Step1.利用方案一中创建的物理表tbl_sales_info建数据集tbl_sales_info。
Step2.交叉表中添加计算字段RN,具体如下图:
Step3.交叉表字段配置如下:
Step4.对字段RN设置“高级计算-累计计算-自定义”,如下图:
累计计算类型选择“按列组内累计”,分组维度选择“司机姓名”,如下图:
Step5.对字段RN设置“排序-高级排序”,在高级排序中选择“司机姓名”升序排列,订单日期(ymdhms)组内升序排列,如下图:
Step6. 在交叉表中展示效果如下,查询2025年9月的订单,RN列显示该订单是对应司机在9月份按照时序排列的订单序号(从1开始),如下图所示:
查询2025年10月的订单,RN列显示该订单是对应司机在10月份按照时序排列的订单序号(从1开始),如下图所示:
如阅读后有任何问题,您可以点击Quick BI产品内右下角【帮助与反馈】按钮与我们取得联系。