因为在写考勤系统原先用的ACCESS 做为后台,改成SQL SERVER后读取6.5万行记录居然死机了?
找了几天才找到原因,高频连接和UPDATA造成SQL SERVER 假锁死也就是后台不工作。测试不去重直接Update插入SQL SERVER,1分钟也才1万条记录,这性能和ACCESS一样了。ACCESS 又没有ADO.NET,只能从存储过程下手了。又学了几天总结出的方案:读取记录后每100条记录合并成一个VALUES值发放给后台存储过程执行去重插入。
实测环境:WIN7/SQL SERVER 2008R2\4G内存\从ACCESS 读取6.5条计录去重插入目标表
读取6.5万条计录用时:17秒
6.5成条记录完成读取和去重插入目标表用时:26秒
性能很完美了,因为从考勤机读取记录也需要耗费时间。
在VBA代码里关闭和开启SQL日志,可以减少SQL日志的疯长。
接收数据后直接插入临时表<#tmpCheckInOut> ,去重插入目标表<dbo.tblCheckInOut>
目标表和临时表的结构只多了一个ID
分享测试VBA代码和存储过程代码:
‘---------------ACCESS VBA 代码 -----------------
Set SQLcnn =<SQL SERVER 连接语句>’自行在平台查找
SQLcnn.Execute "Alter DATABASE [DataSQL] SET RECOVERY simple" ‘关闭SQL 日志
set rst=<10万行记录源连接>
rst.MoveFirst
strSQL = ""
lngj = 0
Do While Not rst.EOF
If strSQL = "" Then
strSQL = "'("
Else
strSQL = strSQL & ",("
End If
strSQL = strSQL & rst.Fields("MachineNo")
strSQL = strSQL & ",''" & rst.Fields("EnrollNo") & "''"
strSQL = strSQL & "," & rst.Fields("dwVMode")
strSQL = strSQL & "," & rst.Fields("dwIOMode")
strSQL = strSQL & ",''" & Format(rst.Fields("dwalltime"), "yyyy-mm-dd hh:nn:ss") & "'')"
lngj = lngj + 1
If lngj = 100 Then ’每100行记录向SQL后台发送更新数据
strSQL = "execute dbo.pro_Insert_UpdatetblCheckInOut " & strSQL & "'"
SQLcnn.Execute strSQL
lngj = 0
strSQL = ""
End If
rst.MoveNext
Loop
If lngj < 100 And strSQL <> "" Then ’最后不足100行,记录向SQL后台发送更新数据
strSQL = "execute dbo.pro_Insert_UpdatetblCheckInOut " & strSQL & "'"
SQLcnn.Execute strSQL
lngj = 0
strSQL = ""
End If
SQLcnn.Execute "Alter DATABASE [DataSQL] SET RECOVERY bulk_logged" ‘开启SQL 日志
‘---------------ACCESS VBA 代码 -----------------
/*pro_Insert_UpdatetblCheckInOut存储过程代码
接收数据后直接插入临时表<#tmpCheckInOut> ,去重插入目标表<dbo.tblCheckInOut> */
USE [DataSQL]
GO
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
Create proc [dbo].[pro_Insert_UpdatetblCheckInOut]
@intoCheckvalues varchar(7000)
as
--创建临时表
IF EXISTS(select * from tempdb..sysobjects where id=object_id('tempdb..#tmpcheckinout'))
BEGIN
Drop TABLE #tmpcheckinout
END
Create TABLE [dbo].[#tmpCheckInOut](
[MachineNo] [int] NULL,
[EnrollNo] [nvarchar](25) NULL,
[dwVMode] [int] NULL,
[dwIOMode] [int] NULL,
[dwalltime] [datetime] NULL)
ON [PRIMARY]
Create UNIQUE CLUSTERED INDEX [idx_tmpcheckio] ON [dbo].[#tmpCheckInOut]
(
[EnrollNo] ASC,
[dwalltime] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = OFF, IGNORE_DUP_KEY = OFF, Drop_EXISTING = OFF, ONLINE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY]
--接收数据后直接插入临时表
declare
@intoCheck varchar(8000),
@intoCheckval varchar(7000)
set @intoCheckval=@intoCheckvalues
set @intoCheck='insert into dbo.#tmpCheckInOut (MachineNo,EnrollNo,dwVMode,dwIOMode,dwalltime) values'+@intoCheckval
EXECUTE (@intoCheck)
--去重日期记录插入tblCheckInOut表
insert into dbo.tblCheckInOut (MachineNO,EnrollNo,dwVMode,dwIOMode,dwalltime)
select a.MachineNO,a.EnrollNo,a.dwVMode,a.dwIOMode,a.dwalltime
from dbo.#tmpCheckInOut a left join
dbo.tblCheckInOut b
on a.EnrollNo=b.EnrollNo and a.dwalltime =b.dwalltime
where b.EnrollNo is null
/*pro_Insert_UpdatetblCheckInOut存储过程代码 */