The approach would not require you to "know" when a manager name has changed
in the data. Instead, one would use a query that gives you the unique
manager names, and then you filter the data for each manager name before you
export the data.
Here is code that will do what you seek ("air code" - not fully tested):
'Start of code
Dim qdf As DAO.QueryDef
Dim dbs As DAO.Database
Dim rstMgr As DAO.Recordset
Dim strSQL As String, strTemp As String, strMgr As String
Const strQName As String = "zExportQuery"
Set dbs = CurrentDb
' Create temporary query that will be used for exporting data;
' give it a dummy SQL statement initially
strTemp = dbs.TableDefs(0).Name
strSQL = "SELECT * FROM [" & strTemp & "] WHERE 1=0;"
Set qdf = dbs.CreateQueryDef(strQName, strSQL)
qdf.Close
strTemp = strQName
' Get list of manager IDs -- note: replace my generic table and field
names
' with the real names of the employees table and the manager ID field
strSQL = "SELECT DISTINCT ManagerID FROM EmployeesTable;"
Set rstMgr = dbs.OpenRecordset(strSQL, dbOpenDynaset, dbReadOnly)
' Now loop through list of manager IDs and create a query for each ID
' so that the data can be exported -- the code assumes that the actual
names
' of the managers are in a lookup table -- again, replace generic names
with
' real names of tables and fields
If rstMgr.EOF = False And rstMgr.BOF = False Then
rstMgr.MoveFirst
Do While rstMgr.EOF = False
strMgr = DLookup("ManagerNameField", "ManagersTable", _
"ManagerID = " & rstMgr!ManagerID.Value)
strSQL = "SELECT * FROM EmployeesTable WHERE " & _
"ManagerID = " & rstMgr!ManagerID.Value & ";"
Set qdf = dbs.QueryDefs(strTemp)
qdf.Name = "q_" & strMgr
strTemp = qdf.Name
qdf.SQL = strSQL
qdf.Close
Set qdf = Nothing
' Replace C:\FolderName\ with actual path
DoCmd.TranferSpreadsheet acExport, acSpreadsheetTypeExcel9, _
strTemp, "C:\FolderName\" & strMgr & Format(Now(), _
"ddMMMyyy_hhnn") & ".xls"
rstMgr.MoveNext
Loop
End If
rstMgr.Close
Set rstMgr = Nothing
dbs.QueryDefs.Delete strTemp
dbs.Close
Set dbs = Nothing
'End of code
Let me know of errors / questions.
--
Ken Snell
<MS ACCESS MVP>
Kelly said:
Hi Ken,
Thanks for your response. I would prefer to use VBA and try to automate
the
process as much as possible.
As far as generating separate queries for each manager, does the manager
name have to be known criteria or can code be used to move through the
records and recognize when the manager name changes?
Thanks again.
:
You'll need to use separate queries to generate the records for each
individual manager, and then export each query separately.
This can be done by a variety of ways, ranging from manually creating the
separate queries and then using them in separate TransferSpreadsheet
actions
(macro or VBA), up to using VBA code to generate the queries on the fly
and
export them individually.
Which approach do you wish to try/use?
--
Ken Snell
<MS ACCESS MVP>
I have a table of employees and their managers. I need to send an Excel
file
to each manager to review the list of their employees. Is there a way
to
export the employee data to separate Excel files grouped by manager?
(ie:
Excel file called Manger.xls which includes only the data for their
respective employees).
Any assistance is much appreciated. Thanks.