原文:
通过调整表union all的顺序优化SQL
操作系统:Windows XP
数据库版本:SQL Server 2005
今天遇到一个SQL,过滤条件是自动生成的,因此,没法通过调整SQL的谓词达到优化的目的,只能去找SQL中的“大表”。有一个视图返回的结果集比较大,如果能调整的话,也只能调整该视图了。
看了一下该视图的结构,里面还套用了另一层视图,直接看最里层视图的查询SQL。
SELECT a.dfeesum_no , a.opr_amt - ISNULL(b.dec_pay, 0) - ISNULL(b.dec_corrpay, 0) - ISNULL(b.dec_deduamt, 0) dec_amt , a.dec_camt - ISNULL(b.dec_pay, 0) - a.dec_comprate * ISNULL(b.dec_deduamt, 0) dec_compamt , a.dec_ramt - ISNULL(b.dec_corrpay, 0) - ( a.dec_comprate - 1 ) * ISNULL(b.dec_deduamt, 0) dec_corramt , a.dec_qty - ISNULL(b.dec_qty, 0) - ISNULL(b.dec_deduqty, 0) opr_qty , ISNULL(b.dec_pay, 0) dec_pay , ISNULL(b.dec_corrpay, 0) dec_corrpay , ISNULL(b.dec_deduqty, 0) dec_deduqty , ISNULL(b.dec_deduamt, 0) dec_deduamt , ISNULL(b.dec_qty, 0) dec_qty FROM ctlm8686 a LEFT JOIN ( SELECT dfeesum_no , SUM(dec_ramt) dec_pay , SUM(dec_corramt) dec_corrpay , SUM(dec_qty) dec_qty , SUM(CASE WHEN flag_dedu = '1' THEN dec_deduamt ELSE 0 END) dec_deduamt , SUM(CASE WHEN flag_dedu = '1' THEN dec_deduqty ELSE 0 END) dec_deduqty FROM dfeepay_03 GROUP BY dfeesum_no ) b ON a.dfeesum_no = b.dfeesum_no UNION ALL SELECT a.dfeesum_no , a.dec_amt - ISNULL(b.dec_pay, 0) - ISNULL(b.dec_corrpay, 0) - ISNULL(b.dec_deduamt, 0) dec_amt , a.dec_compamt - ISNULL(b.dec_pay, 0) - a.dec_comprate * ISNULL(b.dec_deduamt, 0) dec_compamt , a.dec_corramt - ISNULL(b.dec_corrpay, 0) - ( a.dec_comprate - 1 ) * ISNULL(b.dec_deduamt, 0) dec_corramt , a.opr_qty - ISNULL(b.dec_qty, 0) - ISNULL(b.dec_deduqty, 0) opr_qty , ISNULL(b.dec_pay, 0) dec_pay , ISNULL(b.dec_corrpay, 0) dec_corrpay , ISNULL(b.dec_deduqty, 0) dec_deduqty , ISNULL(b.dec_deduamt, 0) dec_deduamt , ISNULL(b.dec_qty, 0) dec_qty FROM dfeeapp_03 a LEFT JOIN ( SELECT dfeesum_no , SUM(dec_ramt) dec_pay , SUM(dec_corramt) dec_corrpay , SUM(dec_qty) dec_qty , SUM(CASE WHEN flag_dedu = '1' THEN dec_deduamt ELSE 0 END) dec_deduamt , SUM(CASE WHEN flag_dedu = '1' THEN dec_deduqty ELSE 0 END) dec_deduqty FROM dfeepay_03 GROUP BY dfeesum_no ) b ON a.dfeesum_no = b.dfeesum_no
返回结果集有1433891行,其中
SELECT COUNT(*) FROM dfeepay_03 --1103914
SELECT COUNT(*) FROM ctlm8686 --1131586
SELECT COUNT(*) FROM dfeeapp_03--302305
上述SQL脚本中,子查询是相同的,即对子查询进行了两次扫描,可以考虑先让dfeeapp_03和ctlm8686union all,再left join dfeepay_03 。同时,对于子查询,先让dfeepay_03 表先查询出flag_dedu = '1'的数据,就不用再进行case when判断了。
改写后的SQL如下
SELECT a.dfeesum_no , a.opr_amt - ISNULL(b.dec_pay, 0) - ISNULL(b.dec_corrpay, 0) - ISNULL(b.dec_deduamt, 0) dec_amt , a.dec_camt - ISNULL(b.dec_pay, 0) - a.dec_comprate * ISNULL(b.dec_deduamt, 0) dec_compamt , a.dec_ramt - ISNULL(b.dec_corrpay, 0) - ( a.dec_comprate - 1 ) * ISNULL(b.dec_deduamt, 0) dec_corramt , a.dec_qty - ISNULL(b.dec_qty, 0) - ISNULL(b.dec_deduqty, 0) opr_qty , ISNULL(b.dec_pay, 0) dec_pay , ISNULL(b.dec_corrpay, 0) dec_corrpay , ISNULL(b.dec_deduqty, 0) dec_deduqty , ISNULL(b.dec_deduamt, 0) dec_deduamt , ISNULL(b.dec_qty, 0) dec_qty FROM ( SELECT a.dfeesum_no , a.opr_amt , a.dec_camt , a.dec_comprate , a.dec_ramt , a.dec_qty FROM ctlm8686 a UNION ALL SELECT a.dfeesum_no , a.dec_amt , a.dec_compamt , a.dec_comprate , a.dec_corramt , a.opr_qty FROM dfeeapp_03 a ) a LEFT JOIN ( SELECT dfeesum_no , SUM(dec_ramt) dec_pay , SUM(dec_corramt) dec_corrpay , SUM(dec_qty) dec_qty , SUM(dec_deduamt) dec_deduamt, SUM(dec_deduqty) dec_deduqty FROM dfeepay_03 WHERE flag_dedu = '1' GROUP BY dfeesum_no ) b ON a.dfeesum_no = b.dfeesum_no
跑这个视图的查询语句,从原来的一分半钟降到一分钟,对于整个SQL而言,则从原来跑几分钟的直接10S出结果。