你的位置:首页 > 数据库

[数据库]实战:上亿数据如何秒查


最近在忙着优化集团公司的一个报表。优化完成后,报表查询速度有从半小时以上(甚至查不出)到秒查的质变。从修改SQL查询语句逻辑到决定创建存储

过程实现,花了我3天多的时间,在此总结一下,希望对朋友们有帮助。

数据背景

首先项目是西门子中国在我司实施部署的MES项目,由于项目是在产线上运作(3 years+),数据累积很大。在项目的数据库中,大概上亿条数据的表有5个以上,千万级数据的表10个以上,百万级数据的表,很多...

(历史问题,当初实施无人监管,无人监控数据库这块的性能问题。ps:我刚入职不久...)

不多说,直接贴西门子中国的开发人员在我司开发的SSRS报表中的SQL语句:

 1 select distinct b.MaterialID as matl_def_id, c.Descript, case when right(b.MESOrderID, 12) < '001000000000' then right(b.MESOrderID, 9)  2 else right(b.MESOrderID, 12) end as pom_order_id, a.LotName, a.SourceLotName as ComLot,  3 e.DefID as ComMaterials, e.Descript as ComMatDes, d.VendorID, d.DateCode,d.SNNote, b.OnPlantID,a.SNCUST 4 from  5 ( 6   select m.lotname, m.sourcelotname, m.opetypeid, m.OperationDate,n.SNCUST from View1 m 7   left join co_sn_link_customer as n on n.SNMes=m.LotName 8   where  9   ( m.LotName in (select val from fn_String_To_Table(@sn,',',1)) or (@sn) = '') and 10   ( m.sourcelotname in (select val from fn_String_To_Table(@BatchID,',',1)) or (@BatchID) = '')11   and (n.SNCust like '%'+ @SN_ext + '%' or (@SN_ext)='')12 ) a13 left join 14 (15   select * from Table1 where SNType = 'IntSN'16   and SNRuleName = 'ProductSNRule'17   and OnPlantID=@OnPlant18 ) b on b.SN = a.LotName19 inner join MMdefinitions as c on c.DefID = b.MaterialID20 left join Table1 as d on d.SN = a.SourceLotName 21 inner join MMDefinitions as e on e.DefID = d.MaterialID22 where not exists (23 select distinct LotName, SourceLotName from ELCV_ASSEMBLE_OPS 24 where LotName = a.SourceLotName and SourceLotName = a.LotName25 ) 26 and (d.DateCode in (select val from fn_String_To_Table(@DCode,',',1)) or (@DCode) = '')27 and (d.SNNote like '%'+@SNNote+'%' or (@SNNote) = '')28 and ((case when right(b.MESOrderID, 12) < '001000000000' then right(b.MESOrderID, 9) 29 else right(b.MESOrderID, 12) end) in (select val from fn_String_To_Table(@order_id,',',1)) or (@order_id) = '')30 and (e.DefID in (select val from fn_String_To_Table(@comdef,',',1)) or (@comdef) = '')31 --View1是一个嵌套两层的视图(出于保密性,实际名称可能不同),里面有一张上亿数据的表和几张千万级数据的表做左连接查询32 --Table1是一个数据记录超过1500万的表

View Code

这个查询语句,实际上通过我的检测和调查,在B/S系统前端已无法查出结果,半小时,一小时 ... 。因为我直接在SQL查询分析器查,半小时都没有结果。

(原因是里面对一张上亿级数据表和3张千万级数据表做全表扫描查询)

不由感慨,西门子中国的素质(或者说责任感)就这样?

下面说说我的分析和走的弯路(思维误区),希望对你也有警醒。

探索和误区

首先相关表的索引,没有建全的,把索引给建上。

索引这步完成后,发现情况还是一样,查询速度几乎没有改善。后来想起相关千万级数据以上的表,都还没有建立表分区。于是考虑建立表分区以及数据复制的方案。

这里有必要说明下:我司报表用的是一个专门的数据库服务器,数据从产线订阅而来。就是常说的“读写分离”。

如果直接在原表上建立表分区,你会发现执行表分区的事物会直接死锁。原因是:表分区操作本身会锁表,产线还在推数据过来,这样很容易“阻塞”,“死锁”。

我想好的方案是:建立一个新表(空表),在新表上建好表分区,然后复制数据过来。

正打算这么干。等等!我好像进入了一个严重的误区!

分析: 原SQL语句和业务需求,是对产线的数据做产品以及序列号的追溯,关键是查询条件里没有有规律的"条件"(如日期、编号),

         贸然做了表分区,在这里几乎没有意义!反而会降低查询性能!

好险!还是一步一步来,先做SQL语句分析。

一. 对原SQL语句的分析

1. 查询语句的where条件,有大量@var in ... or (@var ='') 的片段

2. where条件有like '%'+@var+'%' 

3. where条件有 case ... end 函数

4. 多次连接同一表查询,另外使用本身已嵌套的视图表,是不是必须,是否可替代?

5. SQL语句有*号,视图中也有*号出现

二. 优化设计

首先是用存储过程改写,好处是设计灵活。

核心思想是:用一个或多个查询条件(查询条件要求至少输入一个)得到临时表,每个查询条件如果查到集合,就更新这张临时表,最后汇总的时候,

                 只需判断这个临时表是否有值。以此类推,可以建立多个临时表,将查询条件汇总。

这样做目前来看至少两点好处:1.省去了对变量进行 =@var or (@var='')的判断;

                                        2.抛弃sql拼接,提高代码可读性。

再有就是在书写存储过程,这个过程中要注意:

1. 尽量想办法使用临时表扫描替代全表扫描;

2. 抛弃in和not in语句,使用exists和not exists替代;

3. 和客户确认,模糊查询是否有必要,如没有必要,去掉like语句;

4. 注意建立适当的,符合场景的索引;

5. 踩死 "*" 号;

6. 避免在where条件中对字段进行函数操作;

7. 对实时性要求不高的报表,允许脏读(with(nolock))。

三. 存储过程

如果想参考优化设计片段的详细内容,请参阅SQL代码:

 1 /** 2  * 某某跟踪报表 3  **/ 4 --exec spName1 '','','','','','','公司代号' 5 CREATE Procedure spName1 6  @MESOrderID nvarchar(320), --工单号,最多30个 7  @LotName nvarchar(700),  --产品序列号,最多50个 8  @DateCode nvarchar(500),  --供应商批次号,最多30个 9  @BatchID nvarchar(700),  --组装件序列号/物料批号,最多50个 10  @comdef nvarchar(700),   --组装件物料编码,最多30个 11  @SNCust nvarchar(1600),  --外部序列号,最多50个 12  @OnPlant nvarchar(20)   --平台 13 AS 14 BEGIN 15   SET NOCOUNT ON;  16   /** 17    * 1)定义全局的临时表,先根据六个查询条件的任意一个,得出临时表结果 18    **/ 19   CREATE TABLE #FinalLotName 20   ( 21     LotName NVARCHAR(50),    --序列号 22     SourceLotName NVARCHAR(50), --来源序列号 23     SNCust NVARCHAR(128)    --外部序列号 24   ) 25   --1.1 26   IF @LotName<>'' 27   BEGIN 28     SELECT Val INTO #WorkLot FROM fn_String_To_Table(@LotName,',',1) 29     SELECT LotPK,LotName INTO #WorkLotPK FROM MMLots WITH(NOLOCK) WHERE EXISTS(SELECT 1 FROM #WorkLot b WHERE b.Val=MMLots.LotID) 30      31     --求SourceLotPK只能在这里求 32     SELECT a.LotPK,a.SourceLotPK into #WorkSourcePK FROM MMLotOperations a WITH(NOLOCK) WHERE EXISTS(SELECT 1 FROM #WorkLotPK b WHERE b.LotPK=a.LotPK) AND a.SourceLotPK IS NOT NULL 33      34     SELECT a.LotPK,a.SourceLotPK,b.LotName INTO #WorkSourcePK2 FROM #WorkSourcePK a JOIN #WorkLotPK b ON a.LotPK=b.LotPK 35      36     INSERT INTO #FinalLotName SELECT a.LotName,b.LotName AS SourceLotName,NULL FROM #WorkSourcePK2 a JOIN (SELECT LotPK,LotName FROM MMLots WITH(NOLOCK) ) b on a.SourceLotPK=b.LotPK --b的里面加不加WHERE RowDeleted=0待确定 37     SELECT a.LotName,a.SourceLotName,b.SNCust INTO #FinalLotNameX1 FROM #FinalLotName a LEFT JOIN CO_SN_LINK_CUSTOMER b WITH(NOLOCK) ON a.LotName=b.SNMes 38     DELETE FROM #FinalLotName 39     INSERT INTO #FinalLotName SELECT LotName,SourceLotName,SNCust FROM #FinalLotNameX1 40   END 41   --1.2 42   IF @BatchID<>'' 43   BEGIN 44     SELECT Val INTO #WorkSourceLot FROM fn_String_To_Table(@BatchID,',',1) 45     IF EXISTS(SELECT 1 FROM #FinalLotName)--如果@LotName也不为空 46     BEGIN 47       SELECT a.LotName,a.SourceLotName,a.SNCust INTO #FinalLotNameX2 FROM #FinalLotName a WHERE EXISTS(SELECT 1 FROM #WorkSourceLot b WHERE a.SourceLotName=b.Val) 48       DELETE FROM #FinalLotName 49       INSERT INTO #FinalLotName SELECT LotName,SourceLotName,SNCust FROM #FinalLotNameX2 50     END 51     ELSE --@LotName条件为空 52     BEGIN 53       SELECT LotPK AS SourceLotPK,LotName AS SourceLotName INTO #2 FROM MMLots WITH(NOLOCK) WHERE EXISTS(SELECT 1 FROM #WorkSourceLot b WHERE b.Val=MMLots.LotID) 54       SELECT a.LotPK,a.SourceLotPK into #21 FROM MMLotOperations a WITH(NOLOCK) WHERE EXISTS(SELECT 1 FROM #2 b WHERE b.SourceLotPK=a.SourceLotPK) 55       SELECT a.LotPK,a.SourceLotPK,b.SourceLotName INTO #22 FROM #21 a JOIN #2 b ON a.SourceLotPK=b.SourceLotPK   56       INSERT INTO #FinalLotName SELECT b.LotName,a.SourceLotName,NULL FROM #22 a JOIN (SELECT LotPK,LotName FROM MMLots WITH(NOLOCK) ) b on a.LotPK=b.LotPK --b的里面加不加WHERE RowDeleted=0待确定   57       SELECT a.LotName,a.SourceLotName,b.SNCust INTO #FinalLotNameX21 FROM #FinalLotName a LEFT JOIN CO_SN_LINK_CUSTOMER b WITH(NOLOCK) ON a.LotName=b.SNMes 58       DELETE FROM #FinalLotName 59       INSERT INTO #FinalLotName SELECT LotName,SourceLotName,SNCust FROM #FinalLotNameX21     60     END 61   END 62   --1.3 63   IF @SNCust<>'' 64   BEGIN 65     SELECT Val INTO #WorkCustomSN FROM fn_String_To_Table(@SNCust,',',1) 66     IF EXISTS(SELECT 1 FROM #FinalLotName)--前面两个条件至少有一个有值 67     BEGIN 68       SELECT a.LotName,a.SourceLotName,a.SNCust INTO #FinalLotNameX3 FROM #FinalLotName a WHERE EXISTS(SELECT 1 FROM #WorkCustomSN b WHERE a.SNCust=b.Val) 69       DELETE FROM #FinalLotName  70       INSERT INTO #FinalLotName SELECT LotName,SourceLotName,SNCust FROM #FinalLotNameX3 71     END 72     ELSE 73     BEGIN 74       SELECT a.SNMes INTO #WorkLotX FROM CO_SN_LINK_CUSTOMER a WITH(NOLOCK) WHERE EXISTS(SELECT 1 FROM #WorkCustomSN b WHERE a.SNCust=b.Val) 75       -------------------以下逻辑和变量1(@LotName)类似[先根据外部序列号求解序列号,再照搬第一个判断变量的方式] 76       SELECT LotPK,LotName INTO #WorkLotPKX FROM MMLots WITH(NOLOCK) WHERE EXISTS(SELECT 1 FROM #WorkLotX b WHERE b.SNMes=MMLots.LotID) 77      78       --求SourceLotPK只能在这里求 79       SELECT a.LotPK,a.SourceLotPK into #WorkSourcePKX FROM MMLotOperations a WITH(NOLOCK) WHERE EXISTS(SELECT 1 FROM #WorkLotPKX b WHERE b.LotPK=a.LotPK) AND a.SourceLotPK IS NOT NULL 80        81       SELECT a.LotPK,a.SourceLotPK,b.LotName INTO #WorkSourcePK2X FROM #WorkSourcePKX a JOIN #WorkLotPKX b ON a.LotPK=b.LotPK 82        83       INSERT INTO #FinalLotName SELECT a.LotName,b.LotName AS SourceLotName,NULL FROM #WorkSourcePK2X a JOIN (SELECT LotPK,LotName FROM MMLots WITH(NOLOCK) ) b on a.SourceLotPK=b.LotPK --b的里面加不加WHERE RowDeleted=0待确定 84       SELECT a.LotName,a.SourceLotName,b.SNCust INTO #FinalLotNameX31 FROM #FinalLotName a LEFT JOIN CO_SN_LINK_CUSTOMER b WITH(NOLOCK) ON a.LotName=b.SNMes 85       DELETE FROM #FinalLotName 86       INSERT INTO #FinalLotName SELECT LotName,SourceLotName,SNCust FROM #FinalLotNameX31 87       ----------------------- 88     END 89   END 90    91   /** 92    * 2)定义全局的临时表,用于替换第一个全局临时表。 93    **/ 94   CREATE TABLE #FinalCO_SN 95   ( 96     SN NVARCHAR(50), 97     SourceSN NVARCHAR(50), 98     SNCust NVARCHAR(128), 99     matl_def_id NVARCHAR(50),--sn的物料ID100     ComMaterials NVARCHAR(50), --SourceSN的物料ID101     MESOrderID NVARCHAR(20),102     OnPlantID NVARCHAR(20),103     VendorID NVARCHAR(20),104     DateCode NVARCHAR(20) ,105     SNNote NVARCHAR(512)106   )107   --2.1108   IF @MESOrderID<>''109   BEGIN110     -------------------------------将MESOrderID做特殊处理-----------------------------------111     SELECT Val INTO #WorkMESOrderID FROM fn_String_To_Table(@MESOrderID,',',1)112     IF @OnPlant='Comba'113     BEGIN114       UPDATE #WorkMESOrderID SET Val='C000'+Val WHERE LEN(Val)=9115     END116     ELSE117     BEGIN118       UPDATE #WorkMESOrderID SET Val='W000'+Val WHERE LEN(Val)=9119     END120     SELECT SN,MaterialID,MESOrderID,OnPlantID INTO #WorkCO_SN1 FROM CO_SN_GENERATION a WITH(NOLOCK)121     WHERE SNType='IntSN' AND SNRuleName = 'ProductSNRule' AND OnPlantID=@OnPlant122     AND EXISTS(SELECT 1 FROM #WorkMESOrderID b WHERE a.MESOrderID=b.Val)123     ------------------------------------------------------------------------------------------124     --条件判断(逻辑分析)开始125     IF EXISTS(SELECT 1 FROM #FinalLotName)--如果前面判断的查询条件有值126     BEGIN127       --查出SourceLotName对应的查询字段128       SELECT a.SN AS SourceLotName,a.VendorID,a.DateCode,a.SNNote,a.MaterialID AS ComMaterials INTO #SourceLotNameTable FROM CO_SN_GENERATION a WITH(NOLOCK) WHERE EXISTS(SELECT 1 FROM #FinalLotName b WHERE a.SN=b.SourceLotName)129       130       INSERT INTO #FinalCO_SN131       SELECT a.LotName,a.SourceLotName,d.SNCust,b.MaterialID,c.ComMaterials,b.MESOrderID,b.OnPlantID,c.VendorID,c.DateCode,c.SNNote FROM #FinalLotName a 132       LEFT JOIN #WorkCO_SN1 b ON a.LotName=b.SN133       LEFT JOIN #SourceLotNameTable c ON a.SourceLotName=c.SourceLotName134       LEFT JOIN CO_SN_LINK_CUSTOMER d WITH(NOLOCK) ON a.LotName=d.SNMes135     END136     ELSE137     BEGIN138       --已知SN集合求解对应的SourceSN和SNCust集合------------------------------------------139       SELECT LotPK,LotName INTO #WorkLotPK410 FROM MMLots WITH(NOLOCK) WHERE EXISTS(SELECT 1 FROM #WorkCO_SN1 b WHERE b.SN=MMLots.LotID)140       SELECT a.LotPK,a.SourceLotPK into #WorkSourcePK420 FROM MMLotOperations a WITH(NOLOCK) WHERE EXISTS(SELECT 1 FROM #WorkLotPK410 b WHERE b.LotPK=a.LotPK) AND a.SourceLotPK IS NOT NULL141       SELECT a.LotPK,a.SourceLotPK,b.LotName INTO #WorkSourcePK430 FROM #WorkSourcePK420 a JOIN #WorkLotPK410 b ON a.LotPK=b.LotPK142       INSERT INTO #FinalLotName SELECT a.LotName,b.LotName AS SourceLotName,NULL FROM #WorkSourcePK430 a JOIN (SELECT LotPK,LotName FROM MMLots WITH(NOLOCK) ) b on a.SourceLotPK=b.LotPK --b的里面加不加WHERE RowDeleted=0待确定143       144       SELECT a.LotName,a.SourceLotName,b.SNCust INTO #FinalLotNameX440 FROM #FinalLotName a LEFT JOIN CO_SN_LINK_CUSTOMER b WITH(NOLOCK) ON a.LotName=b.SNMes145       DELETE FROM #FinalLotName146       INSERT INTO #FinalLotName SELECT LotName,SourceLotName,SNCust FROM #FinalLotNameX440147       -------------------------------------------------------------------------------------148       SELECT a.SN AS SourceLotName,a.VendorID,a.DateCode,a.SNNote,a.MaterialID AS ComMaterials INTO #SourceLotNameTable2 FROM CO_SN_GENERATION a WITH(NOLOCK) WHERE EXISTS(SELECT 1 FROM #FinalLotName b WHERE a.SN=b.SourceLotName)149       150       INSERT INTO #FinalCO_SN151       SELECT a.LotName,a.SourceLotName,a.SNCust,b.MaterialID,c.ComMaterials,b.MESOrderID,b.OnPlantID,c.VendorID,c.DateCode,c.SNNote FROM #FinalLotName a 152       LEFT JOIN #WorkCO_SN1 b ON a.LotName=b.SN153       LEFT JOIN #SourceLotNameTable2 c ON a.SourceLotName=c.SourceLotName154     END  155   END156   --2.2157   IF @DateCode<>''158   BEGIN159     SELECT Val INTO #WorkDateCode FROM fn_String_To_Table(@DateCode,',',1)160     --此@DataCode条件求解出来的是SourceSN161     SELECT SN AS SourceSN,MaterialID AS ComMaterials,VendorID,DateCode,SNNote INTO #WorkSourceSNT1 FROM CO_SN_GENERATION a WITH(NOLOCK) WHERE EXISTS(SELECT 1 FROM #WorkDateCode b WHERE a.DateCode=b.Val)162     ----------------------------------------------------------------------------------------------------163     --条件判断(逻辑分析)开始164     IF EXISTS(SELECT 1 FROM #FinalCO_SN)--如果前面判断的查询条件有值165     BEGIN166       SELECT a.LotName,a.SourceLotName,a.SNCust,a.MaterialID,a.ComMaterials,a.MESOrderID,a.OnPlantID,a.VendorID,a.DateCode,a.SNNote INTO #TMP51 FROM #FinalCO_SN a WHERE EXISTS (SELECT 1 FROM #WorkDateCode b WHERE a.DateCode=b.Val)167       DELETE FROM #FinalCO_SN168       INSERT INTO #FinalCO_SN SELECT LotName,SourceLotName,SNCust,MaterialID,ComMaterials,MESOrderID,OnPlantID,VendorID,DateCode,SNNote FROM #TMP51169     END170     ELSE171     BEGIN172       IF EXISTS(SELECT 1 FROM #FinalLotName)173       BEGIN174       --查出SourceLotName对应的查询字段175       SELECT a.SourceSN,a.VendorID,a.DateCode,a.SNNote,a.ComMaterials INTO #SourceLTX5 FROM #WorkSourceSNT1 a WHERE EXISTS(SELECT 1 FROM #FinalLotName b WHERE a.SourceSN=b.SourceLotName)176       --查出SN对应的查询字段177       SELECT SN,MaterialID,MESOrderID,OnPlantID INTO #WorkSNT510 FROM CO_SN_GENERATION a WITH(NOLOCK)178       WHERE SNType='IntSN' AND SNRuleName = 'ProductSNRule' AND OnPlantID=@OnPlant179       AND EXISTS(SELECT 1 FROM #FinalLotName b WHERE a.SN=b.LotName)180       181       INSERT INTO #FinalCO_SN182       SELECT a.LotName,a.SourceLotName,d.SNCust,b.MaterialID,c.ComMaterials,b.MESOrderID,b.OnPlantID,c.VendorID,c.DateCode,c.SNNote FROM #FinalLotName a 183       LEFT JOIN #WorkSNT510 b ON a.LotName=b.SN184       LEFT JOIN #WorkSourceSNT1 c ON a.SourceLotName=c.SourceSN185       LEFT JOIN CO_SN_LINK_CUSTOMER d WITH(NOLOCK) ON a.LotName=d.SNMes186       187       END188       ELSE189       BEGIN190         --已知SourceSN集合求解对应的SN和SNCust集合------------------------------------------191         SELECT LotPK AS SourceLotPK,LotName AS SrouceLotName INTO #WorkLotX510 FROM MMLots WITH(NOLOCK) WHERE EXISTS(SELECT 1 FROM #WorkSourceSNT1 b WHERE b.SourceSN=MMLots.LotID)192         SELECT a.LotPK,a.SourceLotPK into #WorkLotX520 FROM MMLotOperations a WITH(NOLOCK) WHERE EXISTS(SELECT 1 FROM #WorkLotX510 b WHERE b.SourceLotPK=a.SourceLotPK)193         SELECT a.LotPK,a.SourceLotPK,b.SrouceLotName INTO #WorkLotX530 FROM #WorkLotX520 a JOIN #WorkLotX510 b ON a.SourceLotPK=b.SourceLotPK194         195         INSERT INTO #FinalLotName SELECT b.LotName,a.SrouceLotName,NULL FROM #WorkLotX530 a JOIN (SELECT LotPK,LotName FROM MMLots WITH(NOLOCK) ) b on a.LotPK=b.LotPK --b的里面加不加WHERE RowDeleted=0待确定196         197         SELECT a.LotName,a.SourceLotName,b.SNCust INTO #WorkLotX540 FROM #FinalLotName a LEFT JOIN CO_SN_LINK_CUSTOMER b WITH(NOLOCK) ON a.LotName=b.SNMes198         DELETE FROM #FinalLotName199         INSERT INTO #FinalLotName SELECT LotName,SourceLotName,SNCust FROM #WorkLotX540200         -------------------------------------------------------------------------------------201         SELECT SN,MaterialID,MESOrderID,OnPlantID INTO #WorkLotX550 FROM CO_SN_GENERATION a WITH(NOLOCK)202         WHERE SNType='IntSN' AND SNRuleName = 'ProductSNRule' AND OnPlantID=@OnPlant203         AND EXISTS(SELECT 1 FROM #FinalLotName b WHERE a.SN=b.LotName)204       205         INSERT INTO #FinalCO_SN206         SELECT a.LotName,a.SourceLotName,a.SNCust,b.MaterialID,c.ComMaterials,b.MESOrderID,b.OnPlantID,c.VendorID,c.DateCode,c.SNNote FROM #FinalLotName a 207         LEFT JOIN #WorkLotX550 b ON a.LotName=b.SN208         LEFT JOIN #WorkSourceSNT1 c ON a.SourceLotName=c.SourceSN209       END210     END211   END212   --2.3213   IF @comdef<>''214   BEGIN215     SELECT Val INTO #WorkComdef FROM fn_String_To_Table(@comdef,',',1)216     --此@comdef条件求解出来的是SourceSN217     SELECT SN AS SourceSN,MaterialID AS ComMaterials,VendorID,DateCode,SNNote INTO #WorkSourceSNT16 FROM CO_SN_GENERATION a WITH(NOLOCK) WHERE EXISTS(SELECT 1 FROM #WorkComdef b WHERE a.MaterialID=b.Val)218     ----------------------------------------------------------------------------------------------------219     --条件判断(逻辑分析)开始220     IF EXISTS(SELECT 1 FROM #FinalCO_SN)--如果前面判断的查询条件有值221     BEGIN222       SELECT a.LotName,a.SourceLotName,a.SNCust,a.MaterialID,a.ComMaterials,a.MESOrderID,a.OnPlantID,a.VendorID,a.DateCode,a.SNNote INTO #TMP516 FROM #FinalCO_SN a WHERE EXISTS (SELECT 1 FROM #WorkComdef b WHERE a.matl_def_id=b.Val)223       DELETE FROM #FinalCO_SN224       INSERT INTO #FinalCO_SN SELECT LotName,SourceLotName,SNCust,MaterialID,ComMaterials,MESOrderID,OnPlantID,VendorID,DateCode,SNNote FROM #TMP516225     END226     ELSE227     BEGIN228       IF EXISTS(SELECT 1 FROM #FinalLotName)229       BEGIN230       --查出SourceLotName对应的查询字段231       SELECT a.SourceSN,a.VendorID,a.DateCode,a.SNNote,a.ComMaterials INTO #SourceLTX56 FROM #WorkSourceSNT16 a WHERE EXISTS(SELECT 1 FROM #FinalLotName b WHERE a.SourceSN=b.SourceLotName)232       --查出SN对应的查询字段233       SELECT SN,MaterialID,MESOrderID,OnPlantID INTO #WorkSNT5106 FROM CO_SN_GENERATION a WITH(NOLOCK)234       WHERE SNType='IntSN' AND SNRuleName = 'ProductSNRule' AND OnPlantID=@OnPlant235       AND EXISTS(SELECT 1 FROM #FinalLotName b WHERE a.SN=b.LotName)236       237       INSERT INTO #FinalCO_SN238       SELECT a.LotName,a.SourceLotName,d.SNCust,b.MaterialID,c.ComMaterials,b.MESOrderID,b.OnPlantID,c.VendorID,c.DateCode,c.SNNote FROM #FinalLotName a 239       LEFT JOIN #WorkSNT5106 b ON a.LotName=b.SN240       LEFT JOIN #WorkSourceSNT16 c ON a.SourceLotName=c.SourceSN241       LEFT JOIN CO_SN_LINK_CUSTOMER d WITH(NOLOCK) ON a.LotName=d.SNMes242       243       END244       ELSE245       BEGIN246         --已知SourceSN集合求解对应的SN和SNCust集合------------------------------------------247         SELECT LotPK AS SourceLotPK,LotName AS SrouceLotName INTO #WorkLotX5106 FROM MMLots WITH(NOLOCK) WHERE EXISTS(SELECT 1 FROM #WorkSourceSNT16 b WHERE b.SourceSN=MMLots.LotID)248         SELECT a.LotPK,a.SourceLotPK into #WorkLotX5206 FROM MMLotOperations a WITH(NOLOCK) WHERE EXISTS(SELECT 1 FROM #WorkLotX5106 b WHERE b.SourceLotPK=a.SourceLotPK)249         SELECT a.LotPK,a.SourceLotPK,b.SrouceLotName INTO #WorkLotX5306 FROM #WorkLotX5206 a JOIN #WorkLotX5106 b ON a.SourceLotPK=b.SourceLotPK250         251         INSERT INTO #FinalLotName SELECT b.LotName,a.SrouceLotName,NULL FROM #WorkLotX5306 a JOIN (SELECT LotPK,LotName FROM MMLots WITH(NOLOCK) ) b on a.LotPK=b.LotPK --b的里面加不加WHERE RowDeleted=0待确定252         253         SELECT a.LotName,a.SourceLotName,b.SNCust INTO #WorkLotX5406 FROM #FinalLotName a LEFT JOIN CO_SN_LINK_CUSTOMER b WITH(NOLOCK) ON a.LotName=b.SNMes254         DELETE FROM #FinalLotName255         INSERT INTO #FinalLotName SELECT LotName,SourceLotName,SNCust FROM #WorkLotX5406256         -------------------------------------------------------------------------------------257         SELECT SN,MaterialID,MESOrderID,OnPlantID INTO #WorkLotX5506 FROM CO_SN_GENERATION a WITH(NOLOCK)258         WHERE SNType='IntSN' AND SNRuleName = 'ProductSNRule' AND OnPlantID=@OnPlant259         AND EXISTS(SELECT 1 FROM #FinalLotName b WHERE a.SN=b.LotName)260       261         INSERT INTO #FinalCO_SN262         SELECT a.LotName,a.SourceLotName,a.SNCust,b.MaterialID,c.ComMaterials,b.MESOrderID,b.OnPlantID,c.VendorID,c.DateCode,c.SNNote FROM #FinalLotName a 263         LEFT JOIN #WorkLotX5506 b ON a.LotName=b.SN264         LEFT JOIN #WorkSourceSNT16 c ON a.SourceLotName=c.SourceSN265       END266     END267   END268   269   /**270    * 3)条件判断结束271    **/272   IF EXISTS(SELECT 1 FROM #FinalLotName)273   BEGIN274     IF EXISTS(SELECT 1 FROM #FinalCO_SN)275     BEGIN--3.1276       SELECT a.matl_def_id,b.Descript,a.MESOrderID AS pom_order_id,a.SN AS LotName,a.SourceSN AS ComLot,277          a.ComMaterials,c.Descript AS ComMatDes,a.VendorID,a.DateCode,a.SNNote,278          OnPlantID,SNCust FROM #FinalCO_SN a279          JOIN MMDefinitions b WITH(NOLOCK) ON a.matl_def_id=b.DefID280          JOIN MMDefinitions c WITH(NOLOCK) ON a.ComMaterials=c.DefID281       WHERE NOT EXISTS(select distinct SN, SourceSN from #FinalCO_SN x 282               where x.SN = a.SourceSN and x.SourceSN = a.SN)283     END284     ELSE285     BEGIN--3.2286       --3.2.1求解SN的必查字段287       SELECT SN,MaterialID,MESOrderID,OnPlantID INTO #FinalSNX1 FROM CO_SN_GENERATION a WITH(NOLOCK)288       WHERE SNType='IntSN' AND SNRuleName = 'ProductSNRule' AND OnPlantID=@OnPlant289       AND EXISTS(SELECT 1 FROM #FinalLotName b WHERE a.SN=b.LotName)290       --3.2.2求解SourceSN的必查字段291       SELECT a.SN AS SourceLotName,a.VendorID,a.DateCode,a.SNNote,a.MaterialID AS ComMaterials INTO #FinalSNX2 FROM CO_SN_GENERATION a WITH(NOLOCK) WHERE EXISTS(SELECT 1 FROM #FinalLotName b WHERE a.SN=b.SourceLotName)292       293       SELECT b.MaterialID AS matl_def_id,x.Descript,b.MESOrderID AS pom_order_id,b.SN AS LotName,c.SourceLotName AS ComLot,c.ComMaterials,y.Descript AS ComMatDes,c.VendorID,c.DateCode,c.SNNote,b.OnPlantID,a.SNCust294       FROM #FinalLotName a295       LEFT JOIN #FinalSNX1 b ON a.LotName=b.SN296       LEFT JOIN #FinalSNX2 c ON a.SourceLotName=c.SourceLotName297       JOIN MMDefinitions x WITH(NOLOCK) ON b.MaterialID=x.DefID298       JOIN MMDefinitions y WITH(NOLOCK) ON c.ComMaterials=y.DefID299       WHERE NOT EXISTS(300         SELECT DISTINCT * FROM #FinalLotName z301         WHERE z.LotName=a.SourceLotName and z.SourceLotName=a.LotName302       )303     END304   END305   ELSE306   BEGIN307     IF EXISTS(SELECT 1 FROM #FinalCO_SN)308     BEGIN--3.3309       SELECT a.matl_def_id,b.Descript,a.MESOrderID AS pom_order_id,a.SN AS LotName,a.SourceSN AS ComLot,310          a.ComMaterials,c.Descript AS ComMatDes,a.VendorID,a.DateCode,a.SNNote,311          OnPlantID,SNCust FROM #FinalCO_SN a312          JOIN MMDefinitions b WITH(NOLOCK) ON a.matl_def_id=b.DefID313          JOIN MMDefinitions c WITH(NOLOCK) ON a.ComMaterials=c.DefID314       WHERE NOT EXISTS(select distinct SN, SourceSN from #FinalCO_SN x 315               where x.SN = a.SourceSN and x.SourceSN = a.SN)316     END317     ELSE318     BEGIN--3.4319       PRINT 'There is no queryable condition,please enter at less a query conditon.'320     END321   END322   323 END324 GO

View Code

虽然牺牲了代码的可读性,但创造了性能价值。本人水平有限,还请各位不吝赐教!

最后,将SSRS报表替换成此存储过程后,SQL查询分析器是秒查的。B/S前端用时1~2秒!

四. 总结

平常的你是否偶尔会因急于完成任务而书写一堆性能极低的SQL语句呢?写出可靠性能的SQL语句不难,难的是习惯。

本文的优化思想很简单,关键点是避免全表扫描 & 注重SQL语句写法 & 索引,另外,如果你查询的表有可能会在查询时段更新,而实际业务需求允许脏读,可加with(nolock)预防查询被更新事物阻塞。

希望本文对你有帮助。