COMPLEX MACRO to copy visible cells but headers with no data in first row should be ignored

RAM1972

Board Regular
Joined
Jun 29, 2014
Messages
217
Macro to copy non contigious visible cells & columns as below from sheet 1 to sheet 2 in column A1

Take note sheet 1 represents collapse subtotals .there all headers from Columns A 1 to ZZ.

So all headers in which there is no data in first cells should be ignored.

Only those headers with its visible data cells up to end should be copied to sheet 2 with their column size .as esample below .

sheet 1
[TABLE="width: 790"]
<colgroup><col><col span="4"><col><col span="2"><col><col></colgroup><tbody>[TR]
[TD]Columns M
[/TD]
[TD]Columns N[/TD]
[TD]Columns O [/TD]
[TD]Columns P [/TD]
[TD]Columns Q[/TD]
[TD]Columns R[/TD]
[TD]Columns S [/TD]
[TD]Columns T [/TD]
[TD]Columns U
[/TD]
[TD]Columns W
[/TD]
[/TR]
[TR]
[TD]PRODUCT
[/TD]
[TD]Qty_1[/TD]
[TD]Litres [/TD]
[TD]Sugar[/TD]
[TD]Qty [/TD]
[TD]QTY[/TD]
[TD]Unit [/TD]
[TD]@[/TD]
[TD]Amount[/TD]
[TD]Amount[/TD]
[/TR]
[TR]
[TD]COFFEE[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD]1000
[/TD]
[TD="align: right"]23.16
[/TD]
[/TR]
[TR]
[TD]WINES
[/TD]
[TD="align: right"]12
[/TD]
[TD="align: right"]9
[/TD]
[TD="align: right"]0
[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD]2000
[/TD]
[TD="align: right"]15
[/TD]
[/TR]
[TR]
[TD]CONDIMENTS
[/TD]
[TD="align: right"]0
[/TD]
[TD="align: right"]0
[/TD]
[TD="align: right"]0
[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD]300
[/TD]
[TD="align: right"]97.2
[/TD]
[/TR]
[TR]
[TD]BRUSHES[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD]20
[/TD]
[TD="align: right"]9.72
[/TD]
[/TR]
[TR]
[TD]BISCUITS[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD]10
[/TD]
[TD="align: right"]13.68[/TD]
[/TR]
[TR]
[TD]CEREAL[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD]22
[/TD]
[TD="align: right"]74.4
[/TD]
[/TR]
[TR]
[TD]CHOCOLATE[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD]20
[/TD]
[TD="align: right"]5.76
[/TD]
[/TR]
</tbody>[/TABLE]


SHEET 2

EXPECTED RESULTS
[TABLE="width: 480"]
<colgroup><col><col span="4"><col></colgroup><tbody>[TR]
[TD]Columns A
[/TD]
[TD]Columns B[/TD]
[TD]Columns C [/TD]
[TD]Columns D [/TD]
[TD]Columns E[/TD]
[TD]Columns F [/TD]
[/TR]
[TR]
[TD]PRODUCT[/TD]
[TD]Qty_1[/TD]
[TD]Litres [/TD]
[TD]Sugar[/TD]
[TD]Amount[/TD]
[TD]Amount[/TD]
[/TR]
[TR]
[TD]COFFEE[/TD]
[TD="align: right"]0
[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]1000[/TD]
[TD="align: right"]23.16
[/TD]
[/TR]
[TR]
[TD]WINES[/TD]
[TD="align: right"]12[/TD]
[TD="align: right"]9[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]2000[/TD]
[TD="align: right"]15[/TD]
[/TR]
[TR]
[TD]CONDIMENTS[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]300[/TD]
[TD="align: right"]97.2
[/TD]
[/TR]
[TR]
[TD]BRUSHES[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]20[/TD]
[TD="align: right"]9.72[/TD]
[/TR]
[TR]
[TD]BISCUITS[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]10[/TD]
[TD="align: right"]13.68[/TD]
[/TR]
[TR]
[TD]CEREAL[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]22[/TD]
[TD="align: right"]74.4[/TD]
[/TR]
[TR]
[TD]CHOCOLATE[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]20[/TD]
[TD="align: right"]5.76[/TD]
[/TR]
</tbody>[/TABLE]
 

Excel Facts

How to fill five years of quarters?
Type 1Q-2023 in a cell. Grab the fill handle and drag down or right. After 4Q-2023, Excel will jump to 1Q-2024. Dash can be any character.
Macro to copy non contigious visible cells & columns as below from sheet 1 to sheet 2 in column A1

Take note sheet 1 represents collapse subtotals .there all headers from Columns A 1 to ZZ.

So all headers in which there is no data in first cells should be ignored.

Only those headers with its visible data cells up to end should be copied to sheet 2 with their column size .as esample below .

sheet 1
[TABLE="width: 790"]
<colgroup><col><col span="4"><col><col span="2"><col><col></colgroup><tbody>[TR]
[TD]Columns M
[/TD]
[TD]Columns N[/TD]
[TD]Columns O [/TD]
[TD]Columns P [/TD]
[TD]Columns Q[/TD]
[TD]Columns R[/TD]
[TD]Columns S [/TD]
[TD]Columns T [/TD]
[TD]Columns U
[/TD]
[TD]Columns W
[/TD]
[/TR]
[TR]
[TD]PRODUCT
[/TD]
[TD]Qty_1[/TD]
[TD]Litres [/TD]
[TD]Sugar[/TD]
[TD]Qty [/TD]
[TD]QTY[/TD]
[TD]Unit [/TD]
[TD]@[/TD]
[TD]Amount[/TD]
[TD]Amount[/TD]
[/TR]
[TR]
[TD]COFFEE[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD]1000
[/TD]
[TD="align: right"]23.16
[/TD]
[/TR]
[TR]
[TD]WINES
[/TD]
[TD="align: right"]12
[/TD]
[TD="align: right"]9
[/TD]
[TD="align: right"]0
[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD]2000
[/TD]
[TD="align: right"]15
[/TD]
[/TR]
[TR]
[TD]CONDIMENTS
[/TD]
[TD="align: right"]0
[/TD]
[TD="align: right"]0
[/TD]
[TD="align: right"]0
[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD]300
[/TD]
[TD="align: right"]97.2
[/TD]
[/TR]
[TR]
[TD]BRUSHES[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD]20
[/TD]
[TD="align: right"]9.72
[/TD]
[/TR]
[TR]
[TD]BISCUITS[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD]10
[/TD]
[TD="align: right"]13.68[/TD]
[/TR]
[TR]
[TD]CEREAL[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD]22
[/TD]
[TD="align: right"]74.4
[/TD]
[/TR]
[TR]
[TD]CHOCOLATE[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD]20
[/TD]
[TD="align: right"]5.76
[/TD]
[/TR]
</tbody>[/TABLE]


SHEET 2

EXPECTED RESULTS
[TABLE="width: 480"]
<colgroup><col><col span="4"><col></colgroup><tbody>[TR]
[TD]Columns A
[/TD]
[TD]Columns B[/TD]
[TD]Columns C [/TD]
[TD]Columns D [/TD]
[TD]Columns E[/TD]
[TD]Columns F [/TD]
[/TR]
[TR]
[TD]PRODUCT[/TD]
[TD]Qty_1[/TD]
[TD]Litres [/TD]
[TD]Sugar[/TD]
[TD]Amount[/TD]
[TD]Amount[/TD]
[/TR]
[TR]
[TD]COFFEE[/TD]
[TD="align: right"]0
[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]1000[/TD]
[TD="align: right"]23.16
[/TD]
[/TR]
[TR]
[TD]WINES[/TD]
[TD="align: right"]12[/TD]
[TD="align: right"]9[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]2000[/TD]
[TD="align: right"]15[/TD]
[/TR]
[TR]
[TD]CONDIMENTS[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]300[/TD]
[TD="align: right"]97.2
[/TD]
[/TR]
[TR]
[TD]BRUSHES[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]20[/TD]
[TD="align: right"]9.72[/TD]
[/TR]
[TR]
[TD]BISCUITS[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]10[/TD]
[TD="align: right"]13.68[/TD]
[/TR]
[TR]
[TD]CEREAL[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]22[/TD]
[TD="align: right"]74.4[/TD]
[/TR]
[TR]
[TD]CHOCOLATE[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]20[/TD]
[TD="align: right"]5.76[/TD]
[/TR]
</tbody>[/TABLE]

this will do what you are asking based on your instructions and your example.

change ranges and sheet names to match your code

Code:
Sub MOVEONLY()
Dim rngSOU As Range, rngDEST As Range, rngHEAD As Range, rngFIL As Range, _
    cell As Range, cellTEST As Range, rng As Range
Dim lngROW As Long, lngCOL As Long, lngDEST As Long
Dim wsSOU As Worksheet, wsDEST As Worksheet
Dim varI As Variant

    Set wsSOU = Sheets("Sheet3")
    Set wsDEST = Sheets("sheet4")
    
    lngDEST = 1
    
    wsSOU.Select
    With wsSOU
        
        .AutoFilterMode = False
        Set rng = wsSOU.Cells
        lngROW = rng.Find(What:="*", after:=rng.Cells(1), _
            LookAt:=xlPart, LookIn:=xlFormulas, SearchOrder:=xlByRows, _
            SearchDirection:=xlPrevious, MatchCase:=False).Row
        lngCOL = rng.Find(What:="*", after:=rng.Cells(1), _
            LookAt:=xlPart, LookIn:=xlFormulas, SearchOrder:=xlByColumns, _
            SearchDirection:=xlPrevious, MatchCase:=False).Column
        Set rngHEAD = Range(.Cells(1, 1), .Cells(1, lngCOL))
        Set rngFIL = Range(.Cells(1, 1), .Cells(lngROW, lngCOL))
        
        For varI = 1 To lngCOL
            wsSOU.Select
            Set cellTEST = Cells(2, varI)
            If Not cellTEST.Value = vbNullString Or Not cellTEST.Value = "" Then
                Set rngSOU = Range(.Cells(1, varI), .Cells(lngROW, varI))
                rngSOU.SpecialCells(xlCellTypeVisible).Copy
                wsDEST.Select
                With wsDEST
                    Set rngDEST = Cells(1, lngDEST)
                    rngDEST.PasteSpecial xlPasteAll
                End With
                lngDEST = lngDEST + 1
            End If
        Next
    End With
End Sub

regards,
 
Last edited:
Upvote 0

Forum statistics

Threads
1,223,911
Messages
6,175,322
Members
452,635
Latest member
laura12345

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