Copy 5 open workbooks to a 1 new workbook

ratt2581

Board Regular
Joined
Nov 11, 2006
Messages
100
I currently work from five different workbooks and I usually need data from all of them so I tend to copy all five workbooks (each one only contains one sheet) to a new workbook and then run some vlookups from that new workbook.

I was wondering if there was a way to run a macro that could do that copy for me. For example if it could search for workbook X1 (or even sheet X1) and then copy that to NewWorkbook.SheetX1 and then look for workbook (or sheet) XX2 and copy that to NewWorkbook.SheetXX2, etc etc etc

The workbook names always vary in their endings but the beginnings are the same so is there a way to run maybe an if statement. For example:

if left(all open workbook titles) = "ABC" then copy sheet to new workbook.sheet ABC else if left(open workbooks titles) = "XYZ" then copy sheet to new workbook.sheet XYZ

Thanks
 

Excel Facts

Select a hidden cell
Somehide hide payroll data in column G? Press F5. Type G1. Enter. Look in formula bar while you arrow down through G.
I finally figured out what I needed to do - in case anyone else stumbles upon this thread here was my solution (abbreviated)

Code:
Dim Wb As Workbook
Dim LstRowSrc As Long
Dim wsSrc As Worksheet
Dim wsDst As Worksheet

Set QAWb = Workbooks.Add
ActiveWorkbook.Sheets.Add Count:=3

Sheets(1).Name = "Media"
Sheets(2).Name = "PEF"
Sheets(3).Name = "CAF"
Sheets(4).Name = "Creative"
Sheets(5).Name = "Panel"
Sheets(6).Name = "Banner"

Set MediaSh = Sheets(1)
Set PEFSh = Sheets(2)
Set CAFSh = Sheets(3)
Set CreativeSh = Sheets(4)
Set PanelSh = Sheets(5)
Set BannerSh = Sheets(6)



For Each Wb In Workbooks
    If Left(Wb.Name, 3) = "PEF" Then
                    Set wsSrc = Wb.ActiveSheet
                    Set wsDst = PEFSh
                    LstRowSrc = wsSrc.Range("A" & Rows.Count).End(xlUp).Row
                    wsSrc.Range("A1:L" & LstRowSrc).Copy wsDst.Range("A1")
                    Wb.Close
                    
                ElseIf Left(Wb.Name, 3) = "CAF" Then
                    Set wsSrc = Wb.ActiveSheet
                    Set wsDst = CAFSh
                    LstRowSrc = wsSrc.Range("P" & Rows.Count).End(xlUp).Row
                    wsSrc.Range("A1:T" & LstRowSrc).Copy wsDst.Range("A1")
                    Wb.Close
                    
                ElseIf Left(Wb.Name, 3) = "PQA" Then
                    Set wsSrc = Wb.ActiveSheet
                    Set wsDst = PanelSh
                    LstRowSrc = wsSrc.Range("A" & Rows.Count).End(xlUp).Row
                    wsSrc.Range("A1:DZ" & LstRowSrc).Copy wsDst.Range("A1")
                    Wb.Close
                    
               ElseIf Left(Wb.Name, 3) = "CBD" Then
                    Set wsSrc = Wb.ActiveSheet
                    Set wsDst = CreativeSh
                    LstRowSrc = wsSrc.Range("A" & Rows.Count).End(xlUp).Row
                    wsSrc.Range("A1:R" & LstRowSrc).Copy wsDst.Range("A1")
                    Wb.Close
            End If
    Next Wb

hope this can help anyone
 
Upvote 0

Forum statistics

Threads
1,222,032
Messages
6,163,509
Members
451,839
Latest member
HonestZed

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top