copy multiple columns to new sheet

dappy

Board Regular
Joined
Apr 23, 2018
Messages
124
Office Version
  1. 2013
Platform
  1. Windows
Hi folks,

I've had much help before copying columns to another sheet but sadly i'm back here again.

I have this, to copy from sheet1 to sheet2 ignoring the rows with spaces. but i only get what's in column A copied and nothing else? I'd sincerely appreciate any advice.

VBA Code:
Dim ary As Variant, Nary As Variant
   Dim R As Long, C As Long, j As Long
   ary = Intersect(Sheets("sheet1").UsedRange, Sheets("sheet1").Range("A:P"))
   ReDim Nary(1 To UBound(ary, 1) * 5)
   For C = 1 To UBound(ary, 2)
      For R = 1 To UBound(ary, 1)
         If Not IsError(ary(R, C)) Then
            If Not Len(ary(R, C)) = 0 Then
               j = j + 1
               Nary(j) = ary(R, C)
            End If
         End If
      Next R
   Next C
   For R = 1 To j
      Sheets("sheet2").Range("A1").Offset(R).Value = Nary(R)
   Next R

much thanks in advance and have a great weekend!

Carl
 
Last edited by a moderator:
No, if column A is blank then the whole row will be blank
 
Upvote 0

Excel Facts

Get help while writing formula
Click the italics "fx" icon to the left of the formula bar to open the Functions Arguments dialog. Help is displayed for each argument.
Ok, how about
VBA Code:
Sub dappy()
   Dim Ary As Variant, Nary As Variant
   Dim r As Long, c As Long, nr As Long
   
   Ary = Intersect(Sheets("sheet1").UsedRange, Sheets("sheet1").Range("A:P"))
   ReDim Nary(1 To UBound(Ary), 1 To 16)
   For r = 1 To UBound(Ary)
      If Ary(r, 1) <> "" Then
         nr = nr + 1
         For c = 1 To UBound(Ary, 2)
            Nary(nr, c) = Ary(r, c)
         Next c
      End If
   Next r
   Sheets("sheet2").Range("A1").Resize(nr, 16).Value = Nary
End Sub
 
Upvote 0
Solution
Dude, you are amazing, that's absolutely perfect. thank you so much, you're a star!!
 
Upvote 0
You're welcome & thanks for the feedback.
 
Upvote 0
An alternative solution is to use Power Query. Total the columns in a new column. Filter out the nulls. Remove the helper column.

Rich (BB code):
let
    Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content],
    FormatData = Table.TransformColumnTypes(Source,{{"Column1", Int64.Type}, {"Column2", Int64.Type}, {"Column3", Int64.Type}, {"Column4", Int64.Type}, {"Column5", Int64.Type}, {"Column6", Int64.Type}, {"Column7", Int64.Type}, {"Column8", Int64.Type}, {"Column9", Int64.Type}, {"Column10", Int64.Type}, {"Column11", Int64.Type}, {"Column12", Int64.Type}, {"Column13", Int64.Type}, {"Column14", Int64.Type}, {"Column15", Int64.Type}, {"Column16", Int64.Type}}),
    SumColumns = Table.AddColumn(FormatData, "Addition", each List.Sum({[Column1], [Column2], [Column3], [Column4], [Column5], [Column6], [Column7], [Column8], [Column9], [Column10], [Column11], [Column12], [Column13], [Column14], [Column15], [Column16]}), Int64.Type),
    FilterOutNulls = Table.SelectRows(SumColumns, each ([Addition] <> null)),
    RemoveHelper = Table.RemoveColumns(FilterOutNulls,{"Addition"})
in
    RemoveHelper

and based upon Post #11 here is a simpler code. Format cells, filter on Column A.

Rich (BB code):
let
    Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content],
    FormatData = Table.TransformColumnTypes(Source,{{"Column1", Int64.Type}, {"Column2", Int64.Type}, {"Column3", Int64.Type}, {"Column4", Int64.Type}, {"Column5", Int64.Type}, {"Column6", Int64.Type}, {"Column7", Int64.Type}, {"Column8", Int64.Type}, {"Column9", Int64.Type}, {"Column10", Int64.Type}, {"Column11", Int64.Type}, {"Column12", Int64.Type}, {"Column13", Int64.Type}, {"Column14", Int64.Type}, {"Column15", Int64.Type}, {"Column16", Int64.Type}}),
    #"Filtered Rows" = Table.SelectRows(FormatData, each ([Column1] <> null))
in
    #"Filtered Rows"
 
Upvote 0
Thank you Alan, but I don't really understand what I'm meant to do with that??
 
Upvote 0
Try this...

Add in a helper column into the source worksheet with a formula in it that returns a value
to indicate which rows are to be copied.

You can then filter the data using this column and just copy the filtered data using an advanced filter.
 
Upvote 0
@dappy,
Click on the link in my signature to learn about Power Query. It is a part of Excel that allows you to manipulate data without VBA, but with mouse clicks. A very powerful part of Excel that has been around for about 10 years.

Alan
 
Upvote 0

Forum statistics

Threads
1,213,527
Messages
6,114,150
Members
448,552
Latest member
WORKINGWITHNOLEADER

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