Sub 单元格循环() Dim i, j, k, irow Dim cel As Range Dim t AsDouble t = Timer Sheets("查询").Range("a6:d65536").ClearContents Dim str AsString str = Sheets("查询").Range("b3")
k = 5 With Sheets("数据源") ForEach cel In .Range("a2:d" & .[a65536].End(3).Row) 'xlup If cel.Value = str Then k = k + 1 For j = 1To4 Sheets("查询").Cells(k, j) = cel.Offset(0, j - 1) Next EndIf Next EndWith MsgBox Format(Timer - t, "0.000s") EndSub
Sub 数组循环() Dim i, j, k, irow Dim cel As Range Dim t AsDouble t = Timer Sheets("查询").Range("a6:d65536").ClearContents Dim str AsString str = Sheets("查询").Range("b3")
Dim ar, br() 'ar 数据源 ,br 结果 With Sheets("数据源") irow = .[a65536].End(3).Row ar = .Range("a2:d" & irow) EndWith
ReDim br(1To UBound(ar), 1To UBound(ar, 2)) For i = 1To UBound(ar) If ar(i, 1) = str Then k = k + 1 For j = 1To UBound(br, 2) br(k, j) = ar(i, j) Next j EndIf Next i
Sub 字典查询() Dim i, j, k, irow Dim cel As Range Dim t AsDouble t = Timer Sheets("查询").Range("a6:d65536").ClearContents Dim str AsString str = Sheets("查询").Range("b3")
Dim ar, br() 'ar 数据源 ,br 结果 With Sheets("数据源") irow = .[a65536].End(3).Row ar = .Range("a2:d" & irow) EndWith
Dim d AsObject, kw$ Set d = CreateObject("Scripting.Dictionary") 'd.CompareMode = vbTextCompare '不区分大小写
For i = 1To UBound(ar) IfNot d.exists(ar(i, 1)) Then d(ar(i, 1)) = i Else d(ar(i, 1)) = d(ar(i, 1)) & "," & i EndIf Next i
Dim tmpAr tmpAr = Split(d(str), ",")
ReDim br(1To UBound(tmpAr) + 1, 1To UBound(ar, 2)) For i = 0To UBound(tmpAr) For j = 1To UBound(ar, 2) br(i + 1, j) = ar(tmpAr(i), j) Next j Next i
Sub SQL查询() '定义变量 Dim cnn, rst, SQL$ Dim i, j, k Set cnn = CreateObject("adodb.connection") '创建数据库连接 Set rst = CreateObject("adodb.recordset") '创建一个数据集保存数据 Dim t AsDouble t = Timer '设置数据库连接 If Val(Application.Version) < 12Then cnn.Open "Provider=Microsoft.Jet.Oledb.4.0;Extended Properties='Excel 8.0;HDR=yes';Data Source=" & ThisWorkbook.FullName Else cnn.Open "Provider=Microsoft.ACE.OLEDB.12.0;Extended Properties='Excel 12.0;HDR=yes';Data Source=" & ThisWorkbook.FullName EndIf
'设置SQL语句 SQL = "SELECT * FROM [数据源$a1:d100] WHERE 班级='" & Sheets("查询").[B3] & "'"