新建查询批量导出excel
时 间:2017-12-09 08:22:17
作 者:大海 ID:42003 城市:深圳
摘 要:新建查询批量导出excel
正 文:
新建一个查询,根据查询条件把access数据批量导出Excel
Sub accessTOexcel()
Dim strsql As String
Dim qry As DAO.QueryDef
Set qry = CurrentDb.QueryDefs("导出查询")
Dim rst As New ADODB.Recordset
strsql = "Select DISTINCT 供应商 FROM 采购价格"
rst.Open strsql, CurrentProject.Connection, adOpenKeyset, adLockOptimistic
rst.MoveFirst
Do Until rst.EOF
qry.Name = rst(0)
qry.SQL = "select 商品名称,供应商 from 采购价格 where 供应商='" & rst(0) & "'"
If Len(Dir(CurrentProject.Path & "\" & qry.Name & ".xls")) > 0 Then Kill CurrentProject.Path & "\" & qry.Name & ".xls"
DoCmd.TransferSpreadsheet acExport, acSpreadsheetTypeExcel9, qry.Name, CurrentProject.Path & "\" & qry.Name & ".xls", True
rst.MoveNext
Loop
qry.Name = "导出查询"
End Sub
Sub 新建查询()
Dim SQL0 As String
SQL0 = "select * from 采购价格 where 1<>1"
If SQL0 <> "" Then
CreateQuery SQL0, "导出查询"
Application.RefreshDatabaseWindow
End If
End Sub
Private Sub CreateQuery(ByVal ssql As String, QueryName As String)
Dim Qdef As QueryDef
On Error Resume Next
If DCount("*", "MSysObjects", "Type=5 and Name='" & QueryName & "'") = 0 Then
Set Qdef = CurrentDb.CreateQueryDef(QueryName)
Else
Set Qdef = CurrentDb.QueryDefs(QueryName)
End If
Qdef.SQL = ssql
Qdef.Close
Set Qdef = Nothing
End Sub
Sub 删除查询()
On Error Resume Next
DoCmd.DeleteObject acQuery, "导出查询"
Application.RefreshDatabaseWindow
End Sub
Public Function QueryExists(strQueryName As String) As Boolean
Dim accQry As AccessObject
QueryExists = False
For Each accQry In CurrentData.AllQueries
If strQueryName = accQry.Name Then
QueryExists = True
Exit For
End If
Next accQry
End Function
附 件:
图 示:
Access软件网QQ交流群 (群号:54525238) Access源码网店
常见问答:
技术分类:
源码示例
- 【源码QQ群号19834647...(12.17)
- 通过命令按钮让Access列表...(04.24)
- 统计当月之前(不含当月)的记录...(03.11)
- 【Access Inputbo...(03.03)
- 按回车键后光标移动到下一条记录...(02.12)
- 【Access Dsum示例】...(02.07)
- Access对子窗体的数据进行...(02.05)
- 【Access高效办公】上月累...(01.09)
- 【Access高效办公】上月累...(01.06)
- 【Access Inputbo...(12.23)

学习心得
最新文章
- 仓库管理实战课程(15)-月度库存...(04.30)
- Access选择打印机、横纵向、纸...(04.29)
- 仓库管理实战课程(14)-出库功能...(04.26)
- 通过命令按钮让Access列表框指...(04.24)
- 仓库管理实战课程(13)-入库功能...(04.21)
- Access控件美化之--美化按钮...(04.19)
- Access多行文本按指定字符筛选...(04.18)
- Microsoft Access数...(04.18)
- 仓库管理实战课程(12)-月度结存...(04.16)
- 仓库管理实战课程(11)-人性化操...(04.15)