![]() |
#2
|
||||
|
||||
![]()
I would forget about doing this in Word and just stick with Excel and use a macro to build a series of worksheets per game.
I modified your Excel file by adding Table Formatting (aka List Objects) to the two input sheets and added a macro that builds the game lists. Code:
Sub BuildGameRosters() Dim loDraw As ListObject, loRoster As ListObject Dim lrGame As ListRow, rngPlayer As Range Dim aWb As Workbook, aSht As Worksheet, i As Integer Dim sGame As String, sAwayTeam As String, sHomeTeam As String Set aWb = ActiveWorkbook Set loDraw = aWb.Sheets("TestRosterCardData").ListObjects(1) Set loRoster = aWb.Sheets("Rosters").ListObjects(1) 'If the workbook contains more sheets than two, remove extras before recreating Application.DisplayAlerts = False Do While aWb.Sheets.Count > 2 aWb.Sheets(aWb.Sheets.Count).Delete Loop For Each lrGame In loDraw.ListRows sGame = lrGame.Range.Cells(1, 1).Value sAwayTeam = lrGame.Range.Cells(1, 2).Value sHomeTeam = lrGame.Range.Cells(1, 3).Value Set aSht = aWb.Sheets.Add(After:=aWb.Worksheets(aWb.Worksheets.Count)) aSht.Name = "Game " & sGame aSht.Cells(1, 1).Value = aSht.Name aSht.Cells(3, 1).Value = "Home Team" aSht.Cells(3, 2).Value = "Away Team" aSht.Cells(4, 1).Value = sHomeTeam aSht.Cells(4, 2).Value = sAwayTeam aSht.Range("A1:B4").Font.Bold = True loRoster.Range.AutoFilter Field:=1 'clear filter loRoster.Range.AutoFilter Field:=1, Criteria1:=sHomeTeam i = 0 For Each rngPlayer In loRoster.DataBodyRange.SpecialCells(xlCellTypeVisible).Rows i = i + 1 aSht.Cells(4, 1).Offset(i, 0) = rngPlayer.Cells(1, 2) & ", " & rngPlayer.Cells(1, 3) Next rngPlayer loRoster.Range.AutoFilter Field:=1 'clear filter loRoster.Range.AutoFilter Field:=1, Criteria1:=sAwayTeam i = 0 For Each rngPlayer In loRoster.DataBodyRange.SpecialCells(xlCellTypeVisible).Rows i = i + 1 aSht.Cells(4, 2).Offset(i, 0) = rngPlayer.Cells(1, 2) & ", " & rngPlayer.Cells(1, 3) Next rngPlayer aSht.Columns.AutoFit loRoster.Range.AutoFilter Field:=1 'clear filter Next lrGame End Sub
__________________
Andrew Lockton Chrysalis Design, Melbourne Australia |
|
![]() |
||||
Thread | Thread Starter | Forum | Replies | Last Post |
![]() |
sureshbvs | Word VBA | 1 | 03-12-2021 05:42 AM |
![]() |
coopfab | Mail Merge | 2 | 10-02-2019 06:18 AM |
![]() |
CarlCarl2 | Mail Merge | 1 | 01-24-2017 05:53 AM |
Mail merge only sends some email from Access database | rsakai2 | Mail Merge | 4 | 10-30-2013 10:32 PM |
![]() |
rec | Mail Merge | 1 | 09-29-2013 08:03 PM |