最近在忙着优化集团公司的一个报表。优化完成后,报表查询速度有从半小时以上(甚至查不出)到秒查的质变。从修改sql查询语句逻辑到决定创建存储过程实现,花了我3天多的时间,在此总结一下,希望对朋友们有帮助。
数据背景
首先项目是西门子中国在我司实施部署的mes项目,由于项目是在产线上运作(3 years ),数据累积很大。在项目的数据库中,大概上亿条数据的表有5个以上,千万级数据的表10个以上,百万级数据的表,很多…
(历史问题,当初实施无人监管,无人监控数据库这块的性能问题。ps:我刚入职不久…)
不多说,直接贴西门子中国的开发人员在我司开发的ssrs报表中的sql语句:
select distinct b.materialid as matl_def_id, c.descript, case when right(b.mesorderid, 12) < '001000000000' then right(b.mesorderid, 9)
else right(b.mesorderid, 12) end as pom_order_id, a.lotname, a.sourcelotname as comlot,
e.defid as commaterials, e.descript as commatdes, d.vendorid, d.datecode,d.snnote, b.onplantid,a.sncust
from
(
select m.lotname, m.sourcelotname, m.opetypeid, m.operationdate,n.sncust from view1 m
left join co_sn_link_customer as n on n.snmes=m.lotname
where
( m.lotname in (select val from fn_string_to_table(@sn,',',1)) or (@sn) = '') and
( m.sourcelotname in (select val from fn_string_to_table(@batchid,',',1)) or (@batchid) = '')
and (n.sncust like '%' @sn_ext '%' or (@sn_ext)='')
) a
left join
(
select * from table1 where sntype = 'intsn'
and snrulename = 'productsnrule'
and onplantid=@onplant
) b on b.sn = a.lotname
inner join mmdefinitions as c on c.defid = b.materialid
left join table1 as d on d.sn = a.sourcelotname
inner join mmdefinitions as e on e.defid = d.materialid
where not exists (
select distinct lotname, sourcelotname from elcv_assemble_ops
where lotname = a.sourcelotname and sourcelotname = a.lotname
)
and (d.datecode in (select val from fn_string_to_table(@dcode,',',1)) or (@dcode) = '')
and (d.snnote like '%' @snnote '%' or (@snnote) = '')
and ((case when right(b.mesorderid, 12) < '001000000000' then right(b.mesorderid, 9)
else right(b.mesorderid, 12) end) in (select val from fn_string_to_table(@order_id,',',1)) or (@order_id) = '')
and (e.defid in (select val from fn_string_to_table(@comdef,',',1)) or (@comdef) = '')
--view1是一个嵌套两层的视图(出于保密性,实际名称可能不同),里面有一张上亿数据的表和几张千万级数据的表做左连接查询
--table1是一个数据记录超过1500万的表
这个查询语句,实际上通过我的检测和调查,在b/s系统前端已无法查出结果,半小时,一小时 … 。因为我直接在sql查询分析器查,半小时都没有结果。
(原因是里面对一张上亿级数据表和3张千万级数据表做全表扫描查询)
不由感慨,西门子中国的素质(或者说责任感)就这样?
下面说说我的分析和走的弯路(思维误区),希望对你也有警醒。
探索和误区
首先相关表的索引,没有建全的,把索引给建上。
索引这步完成后,发现情况还是一样,查询速度几乎没有改善。后来想起相关千万级数据以上的表,都还没有建立表分区。于是考虑建立表分区以及数据复制的方案。
这里有必要说明下:我司报表用的是一个专门的数据库服务器,数据从产线订阅而来。就是常说的“读写分离”。
如果直接在原表上建立表分区,你会发现执行表分区的事物会直接死锁。原因是:表分区操作本身会锁表,产线还在推数据过来,这样很容易“阻塞”,“死锁”。
我想好的方案是:建立一个新表(空表),在新表上建好表分区,然后复制数据过来。
正打算这么干。等等!我好像进入了一个严重的误区!
分析:原sql语句和业务需求,是对产线的数据做产品以及序列号的追溯,关键是查询条件里没有有规律的”条件”(如日期、编号),
贸然做了表分区,在这里几乎没有意义!反而会降低查询性能!
好险!还是一步一步来,先做sql语句分析。
一. 对原sql语句的分析
-
查询语句的where条件,有大量@var in … or (@var =”) 的片段
-
where条件有like ‘%’ @var ’%’
-
where条件有 case … end 函数
-
多次连接同一表查询,另外使用本身已嵌套的视图表,是不是必须,是否可替代?
-
sql语句有号,视图中也有号出现
二. 优化设计
首先是用存储过程改写,好处是设计灵活。
核心思想是:用一个或多个查询条件(查询条件要求至少输入一个)得到临时表,每个查询条件如果查到集合,就更新这张临时表,最后汇总的时候,只需判断这个临时表是否有值。以此类推,可以建立多个临时表,将查询条件汇总。
image
这样做目前来看至少两点好处:
-
省去了对变量进行 =@var or (@var=”)的判断;
-
抛弃sql拼接,提高代码可读性。
再有就是在书写存储过程,这个过程中要注意:
-
尽量想办法使用临时表扫描替代全表扫描;
-
抛弃in和not in语句,使用exists和not exists替代;
-
和客户确认,模糊查询是否有必要,如没有必要,去掉like语句;
-
注意建立适当的,符合场景的索引;
-
踩死 “*” 号;
-
避免在where条件中对字段进行函数操作;
-
对实时性要求不高的报表,允许脏读(with(nolock))。
三. 存储过程
如果想参考优化设计片段的详细内容,请参阅sql代码:
/**
* 某某跟踪报表
**/
--exec spname1 '','','','','','','公司代号'
create procedure spname1
@mesorderid nvarchar(320), --工单号,最多30个
@lotname nvarchar(700), --产品序列号,最多50个
@datecode nvarchar(500), --供应商批次号,最多30个
@batchid nvarchar(700), --组装件序列号/物料批号,最多50个
@comdef nvarchar(700), --组装件物料编码,最多30个
@sncust nvarchar(1600), --外部序列号,最多50个
@onplant nvarchar(20) --平台
as
begin
set nocount on;
/**
* 1)定义全局的临时表,先根据六个查询条件的任意一个,得出临时表结果
**/
create table #finallotname
(
lotname nvarchar(50), --序列号
sourcelotname nvarchar(50), --来源序列号
sncust nvarchar(128) --外部序列号
)
--1.1
if @lotname<>''
begin
select val into #worklot from fn_string_to_table(@lotname,',',1)
select lotpk,lotname into #worklotpk from mmlots with(nolock) where exists(select 1 from #worklot b where b.val=mmlots.lotid)
--求sourcelotpk只能在这里求
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
select a.lotpk,a.sourcelotpk,b.lotname into #worksourcepk2 from #worksourcepk a join #worklotpk b on a.lotpk=b.lotpk
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待确定
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
delete from #finallotname
insert into #finallotname select lotname,sourcelotname,sncust from #finallotnamex1
end
--1.2
if @batchid<>''
begin
select val into #worksourcelot from fn_string_to_table(@batchid,',',1)
if exists(select 1 from #finallotname)--如果@lotname也不为空
begin
select a.lotname,a.sourcelotname,a.sncust into #finallotnamex2 from #finallotname a where exists(select 1 from #worksourcelot b where a.sourcelotname=b.val)
delete from #finallotname
insert into #finallotname select lotname,sourcelotname,sncust from #finallotnamex2
end
else --@lotname条件为空
begin
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)
select a.lotpk,a.sourcelotpk into #21 from mmlotoperations a with(nolock) where exists(select 1 from #2 b where b.sourcelotpk=a.sourcelotpk)
select a.lotpk,a.sourcelotpk,b.sourcelotname into #22 from #21 a join #2 b on a.sourcelotpk=b.sourcelotpk
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待确定
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
delete from #finallotname
insert into #finallotname select lotname,sourcelotname,sncust from #finallotnamex21
end
end
--1.3
if @sncust<>''
begin
select val into #workcustomsn from fn_string_to_table(@sncust,',',1)
if exists(select 1 from #finallotname)--前面两个条件至少有一个有值
begin
select a.lotname,a.sourcelotname,a.sncust into #finallotnamex3 from #finallotname a where exists(select 1 from #workcustomsn b where a.sncust=b.val)
delete from #finallotname
insert into #finallotname select lotname,sourcelotname,sncust from #finallotnamex3
end
else
begin
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)
-------------------以下逻辑和变量1(@lotname)类似[先根据外部序列号求解序列号,再照搬第一个判断变量的方式]
select lotpk,lotname into #worklotpkx from mmlots with(nolock) where exists(select 1 from #worklotx b where b.snmes=mmlots.lotid)
--求sourcelotpk只能在这里求
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
select a.lotpk,a.sourcelotpk,b.lotname into #worksourcepk2x from #worksourcepkx a join #worklotpkx b on a.lotpk=b.lotpk
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待确定
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
delete from #finallotname
insert into #finallotname select lotname,sourcelotname,sncust from #finallotnamex31
-----------------------
end
end
/**
* 2)定义全局的临时表,用于替换第一个全局临时表。
**/
create table #finalco_sn
(
sn nvarchar(50),
sourcesn nvarchar(50),
sncust nvarchar(128),
matl_def_id nvarchar(50),--sn的物料id
commaterials nvarchar(50), --sourcesn的物料id
mesorderid nvarchar(20),
onplantid nvarchar(20),
vendorid nvarchar(20),
datecode nvarchar(20) ,
snnote nvarchar(512)
)
--2.1
if @mesorderid<>''
begin
-------------------------------将mesorderid做特殊处理-----------------------------------
select val into #workmesorderid from fn_string_to_table(@mesorderid,',',1)
if @onplant='comba'
begin
update #workmesorderid set val='c000' val where len(val)=9
end
else
begin
update #workmesorderid set val='w000' val where len(val)=9
end
select sn,materialid,mesorderid,onplantid into #workco_sn1 from co_sn_generation a with(nolock)
where sntype='intsn' and snrulename = 'productsnrule' and onplantid=@onplant
and exists(select 1 from #workmesorderid b where a.mesorderid=b.val)
------------------------------------------------------------------------------------------
--条件判断(逻辑分析)开始
if exists(select 1 from #finallotname)--如果前面判断的查询条件有值
begin
--查出sourcelotname对应的查询字段
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)
insert into #finalco_sn
select a.lotname,a.sourcelotname,d.sncust,b.materialid,c.commaterials,b.mesorderid,b.onplantid,c.vendorid,c.datecode,c.snnote from #finallotname a
left join #workco_sn1 b on a.lotname=b.sn
left join #sourcelotnametable c on a.sourcelotname=c.sourcelotname
left join co_sn_link_customer d with(nolock) on a.lotname=d.snmes
end
else
begin
--已知sn集合求解对应的sourcesn和sncust集合------------------------------------------
select lotpk,lotname into #worklotpk410 from mmlots with(nolock) where exists(select 1 from #workco_sn1 b where b.sn=mmlots.lotid)
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 null
select a.lotpk,a.sourcelotpk,b.lotname into #worksourcepk430 from #worksourcepk420 a join #worklotpk410 b on a.lotpk=b.lotpk
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待确定
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.snmes
delete from #finallotname
insert into #finallotname select lotname,sourcelotname,sncust from #finallotnamex440
-------------------------------------------------------------------------------------
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)
insert into #finalco_sn
select a.lotname,a.sourcelotname,a.sncust,b.materialid,c.commaterials,b.mesorderid,b.onplantid,c.vendorid,c.datecode,c.snnote from #finallotname a
left join #workco_sn1 b on a.lotname=b.sn
left join #sourcelotnametable2 c on a.sourcelotname=c.sourcelotname
end
end
--2.2
if @datecode<>''
begin
select val into #workdatecode from fn_string_to_table(@datecode,',',1)
--此@datacode条件求解出来的是sourcesn
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)
----------------------------------------------------------------------------------------------------
--条件判断(逻辑分析)开始
if exists(select 1 from #finalco_sn)--如果前面判断的查询条件有值
begin
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)
delete from #finalco_sn
insert into #finalco_sn select lotname,sourcelotname,sncust,materialid,commaterials,mesorderid,onplantid,vendorid,datecode,snnote from #tmp51
end
else
begin
if exists(select 1 from #finallotname)
begin
--查出sourcelotname对应的查询字段
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)
--查出sn对应的查询字段
select sn,materialid,mesorderid,onplantid into #worksnt510 from co_sn_generation a with(nolock)
where sntype='intsn' and snrulename = 'productsnrule' and onplantid=@onplant
and exists(select 1 from #finallotname b where a.sn=b.lotname)
insert into #finalco_sn
select a.lotname,a.sourcelotname,d.sncust,b.materialid,c.commaterials,b.mesorderid,b.onplantid,c.vendorid,c.datecode,c.snnote from #finallotname a
left join #worksnt510 b on a.lotname=b.sn
left join #worksourcesnt1 c on a.sourcelotname=c.sourcesn
left join co_sn_link_customer d with(nolock) on a.lotname=d.snmes
end
else
begin
--已知sourcesn集合求解对应的sn和sncust集合------------------------------------------
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)
select a.lotpk,a.sourcelotpk into #worklotx520 from mmlotoperations a with(nolock) where exists(select 1 from #worklotx510 b where b.sourcelotpk=a.sourcelotpk)
select a.lotpk,a.sourcelotpk,b.sroucelotname into #worklotx530 from #worklotx520 a join #worklotx510 b on a.sourcelotpk=b.sourcelotpk
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待确定
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.snmes
delete from #finallotname
insert into #finallotname select lotname,sourcelotname,sncust from #worklotx540
-------------------------------------------------------------------------------------
select sn,materialid,mesorderid,onplantid into #worklotx550 from co_sn_generation a with(nolock)
where sntype='intsn' and snrulename = 'productsnrule' and onplantid=@onplant
and exists(select 1 from #finallotname b where a.sn=b.lotname)
insert into #finalco_sn
select a.lotname,a.sourcelotname,a.sncust,b.materialid,c.commaterials,b.mesorderid,b.onplantid,c.vendorid,c.datecode,c.snnote from #finallotname a
left join #worklotx550 b on a.lotname=b.sn
left join #worksourcesnt1 c on a.sourcelotname=c.sourcesn
end
end
end
--2.3
if @comdef<>''
begin
select val into #workcomdef from fn_string_to_table(@comdef,',',1)
--此@comdef条件求解出来的是sourcesn
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)
----------------------------------------------------------------------------------------------------
--条件判断(逻辑分析)开始
if exists(select 1 from #finalco_sn)--如果前面判断的查询条件有值
begin
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)
delete from #finalco_sn
insert into #finalco_sn select lotname,sourcelotname,sncust,materialid,commaterials,mesorderid,onplantid,vendorid,datecode,snnote from #tmp516
end
else
begin
if exists(select 1 from #finallotname)
begin
--查出sourcelotname对应的查询字段
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)
--查出sn对应的查询字段
select sn,materialid,mesorderid,onplantid into #worksnt5106 from co_sn_generation a with(nolock)
where sntype='intsn' and snrulename = 'productsnrule' and onplantid=@onplant
and exists(select 1 from #finallotname b where a.sn=b.lotname)
insert into #finalco_sn
select a.lotname,a.sourcelotname,d.sncust,b.materialid,c.commaterials,b.mesorderid,b.onplantid,c.vendorid,c.datecode,c.snnote from #finallotname a
left join #worksnt5106 b on a.lotname=b.sn
left join #worksourcesnt16 c on a.sourcelotname=c.sourcesn
left join co_sn_link_customer d with(nolock) on a.lotname=d.snmes
end
else
begin
--已知sourcesn集合求解对应的sn和sncust集合------------------------------------------
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)
select a.lotpk,a.sourcelotpk into #worklotx5206 from mmlotoperations a with(nolock) where exists(select 1 from #worklotx5106 b where b.sourcelotpk=a.sourcelotpk)
select a.lotpk,a.sourcelotpk,b.sroucelotname into #worklotx5306 from #worklotx5206 a join #worklotx5106 b on a.sourcelotpk=b.sourcelotpk
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待确定
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.snmes
delete from #finallotname
insert into #finallotname select lotname,sourcelotname,sncust from #worklotx5406
-------------------------------------------------------------------------------------
select sn,materialid,mesorderid,onplantid into #worklotx5506 from co_sn_generation a with(nolock)
where sntype='intsn' and snrulename = 'productsnrule' and onplantid=@onplant
and exists(select 1 from #finallotname b where a.sn=b.lotname)
insert into #finalco_sn
select a.lotname,a.sourcelotname,a.sncust,b.materialid,c.commaterials,b.mesorderid,b.onplantid,c.vendorid,c.datecode,c.snnote from #finallotname a
left join #worklotx5506 b on a.lotname=b.sn
left join #worksourcesnt16 c on a.sourcelotname=c.sourcesn
end
end
end
/**
* 3)条件判断结束
**/
if exists(select 1 from #finallotname)
begin
if exists(select 1 from #finalco_sn)
begin--3.1
select a.matl_def_id,b.descript,a.mesorderid as pom_order_id,a.sn as lotname,a.sourcesn as comlot,
a.commaterials,c.descript as commatdes,a.vendorid,a.datecode,a.snnote,
onplantid,sncust from #finalco_sn a
join mmdefinitions b with(nolock) on a.matl_def_id=b.defid
join mmdefinitions c with(nolock) on a.commaterials=c.defid
where not exists(select distinct sn, sourcesn from #finalco_sn x
where x.sn = a.sourcesn and x.sourcesn = a.sn)
end
else
begin--3.2
--3.2.1求解sn的必查字段
select sn,materialid,mesorderid,onplantid into #finalsnx1 from co_sn_generation a with(nolock)
where sntype='intsn' and snrulename = 'productsnrule' and onplantid=@onplant
and exists(select 1 from #finallotname b where a.sn=b.lotname)
--3.2.2求解sourcesn的必查字段
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)
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.sncust
from #finallotname a
left join #finalsnx1 b on a.lotname=b.sn
left join #finalsnx2 c on a.sourcelotname=c.sourcelotname
join mmdefinitions x with(nolock) on b.materialid=x.defid
join mmdefinitions y with(nolock) on c.commaterials=y.defid
where not exists(
select distinct * from #finallotname z
where z.lotname=a.sourcelotname and z.sourcelotname=a.lotname
)
end
end
else
begin
if exists(select 1 from #finalco_sn)
begin--3.3
select a.matl_def_id,b.descript,a.mesorderid as pom_order_id,a.sn as lotname,a.sourcesn as comlot,
a.commaterials,c.descript as commatdes,a.vendorid,a.datecode,a.snnote,
onplantid,sncust from #finalco_sn a
join mmdefinitions b with(nolock) on a.matl_def_id=b.defid
join mmdefinitions c with(nolock) on a.commaterials=c.defid
where not exists(select distinct sn, sourcesn from #finalco_sn x
where x.sn = a.sourcesn and x.sourcesn = a.sn)
end
else
begin--3.4
print 'there is no queryable condition,please enter at less a query conditon.'
end
end
end
go
虽然牺牲了代码的可读性,但创造了性能价值。本人水平有限,还请各位不吝赐教!
最后,将ssrs报表替换成此存储过程后,sql查询分析器是秒查的。b/s前端用时1~2秒!
四. 总结
平常的你是否偶尔会因急于完成任务而书写一堆性能极低的sql语句呢?写出可靠性能的sql语句不难,难的是习惯。
本文的优化思想很简单,关键点是避免全表扫描 & 注重sql语句写法 & 索引,另外,如果你查询的表有可能会在查询时段更新,而实际业务需求允许脏读,可加with(nolock)预防查询被更新事物阻塞。