Macro: Copy entire column into new sheets based on criteria listed in range in another sheet (excel 2010)

RyndaRaw

New Member
Joined
Jan 10, 2021
Messages
5
Office Version
  1. 365
  2. 2019
Platform
  1. Windows
Hi,

I need help trying to create a macro.

I have column Row 1 - Headers - User name.
I want to create a macro that will copy the entire column into a new sheet IF the name in Row 1 matches a range of approved user names in another sheet.

See below example:

Input SheetApproved Name SheetReturn Approved Names with all column values on New Sheet
ValueName 1Name 2Name 3Name 4Approved NamesValueName 1Name 4
AlpaXXName 1AlpaX
BetaXTName 4BetaT
GammaXXXGammaXXX
 

Excel Facts

Which lookup functions find a value equal or greater than the lookup value?
MATCH uses -1 to find larger value (lookup table must be sorted ZA). XLOOKUP uses 1 to find values greater and does not need to be sorted.
You will need to edit the sheet names and possibly the rows, It was unclear if everything started in row 1 on all three sheets.

VBA Code:
Sub at()
Dim sh1 As Worksheet, sh2 As Worksheet, sh3 As Worksheet, c As Range
Set sh1 = Sheets("Input")
Set sh2 = Sheets("Approved Name")
Set sh3 = Sheets("Return Approved Names")
    With sh1
        For Each c In .Range("B1", .Cells(1, Columns.Count).End(xlToLeft))
            If Application.CountIf(sh2.Range("A:A"), c.Value) > 0 Then
                Intersect(c.EntireColumn, .UsedRange).Copy sh3.Cells(1, Columns.Count).End(xlToLeft).Offset(, 1)
            End If
        Next
    End With
End Sub
 
Upvote 0
You will need to edit the sheet names and possibly the rows, It was unclear if everything started in row 1 on all three sheets.

VBA Code:
Sub at()
Dim sh1 As Worksheet, sh2 As Worksheet, sh3 As Worksheet, c As Range
Set sh1 = Sheets("Input")
Set sh2 = Sheets("Approved Name")
Set sh3 = Sheets("Return Approved Names")
    With sh1
        For Each c In .Range("B1", .Cells(1, Columns.Count).End(xlToLeft))
            If Application.CountIf(sh2.Range("A:A"), c.Value) > 0 Then
                Intersect(c.EntireColumn, .UsedRange).Copy sh3.Cells(1, Columns.Count).End(xlToLeft).Offset(, 1)
            End If
        Next
    End With
End Sub
Hi Mr. Whiz :),

the macro worked, I forgot to include that I needed all rows for the description columns (Desc 1 to 4 are Columns A to D) to get returned with the columns (that matched the names from the approved tab).

Everything does start in row 1 on all 3 sheets. They all have headers in Row 1.

When I ran the macro - I did get an error though. It's a pretty big file and it has to search through 200K+ rows and columns. I know this could be a limitation of using macros. Any thoughts on how I can execute on such a large file?


Desc 1Desc 2Desc 3Desc 4Name 1Name 2Name 3Name 4
RedWideTallPolkaToddMegJohnLaine

Thank you so much, I'm pretty new to macros/vba and have spent weeks trying to write what you wrote so quickly :)
 
Upvote 0
This will adjjust for the four description columns as far as copying the correct columns.

VBA Code:
Sub at()
Dim sh1 As Worksheet, sh2 As Worksheet, sh3 As Worksheet, c As Range
Set sh1 = Sheets("Input")
Set sh2 = Sheets("Approved Name")
Set sh3 = Sheets("Return Approved Names")
    With sh1
        For Each c In .Range("E1", .Cells(1, Columns.Count).End(xlToLeft))
            If Application.CountIf(sh2.Range("A:A"), c.Value) > 0 Then
                Intersect(c.EntireColumn, .UsedRange).Copy sh3.Cells(1, Columns.Count).End(xlToLeft).Offset(, 1)
            End If
        Next
    End With
End Sub

I suggest that for copying the data in columns A:D of the input sheet, that you start a new thread since ithe "Oh I forgot" exceeds the scope of the original post, and there is insuffucient detail to know if exactly what descriptive data you want to copy over, nor where you want it pasted on the Return sheet.
 
Upvote 0
This will adjjust for the four description columns as far as copying the correct columns.

VBA Code:
Sub at()
Dim sh1 As Worksheet, sh2 As Worksheet, sh3 As Worksheet, c As Range
Set sh1 = Sheets("Input")
Set sh2 = Sheets("Approved Name")
Set sh3 = Sheets("Return Approved Names")
    With sh1
        For Each c In .Range("E1", .Cells(1, Columns.Count).End(xlToLeft))
            If Application.CountIf(sh2.Range("A:A"), c.Value) > 0 Then
                Intersect(c.EntireColumn, .UsedRange).Copy sh3.Cells(1, Columns.Count).End(xlToLeft).Offset(, 1)
            End If
        Next
    End With
End Sub

I suggest that for copying the data in columns A:D of the input sheet, that you start a new thread since ithe "Oh I forgot" exceeds the scope of the original post, and there is insuffucient detail to know if exactly what descriptive data you want to copy over, nor where you want it pasted on the Return sheet.


Macro: Copy entire column into new sheets based on criteria listed in range in another sheet AND also first 4 columns copied onto new sheet | MrExcel Message Board

I just posted a new thread with the additional scope.

Thanks JLGWhiz.
 
Upvote 0

Forum statistics

Threads
1,224,823
Messages
6,181,181
Members
453,022
Latest member
Mohamed Magdi Tawfiq Emam

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