Editing a macro to only select rows with data in

LouHenry

New Member
Joined
May 2, 2017
Messages
3
<style type="text/css">p.p1 {margin: 0.0px 0.0px 0.0px 0.0px; line-height: 16.0px; font: 13.0px Verdana; color: #232323; -webkit-text-stroke: #232323}p.p2 {margin: 0.0px 0.0px 0.0px 0.0px; line-height: 16.0px; font: 13.0px Verdana; color: #232323; -webkit-text-stroke: #232323; min-height: 16.0px}p.p3 {margin: 0.0px 0.0px 0.0px 0.0px; line-height: 16.0px; font: 13.0px Verdana; color: #ff2500; -webkit-text-stroke: #ff2500}span.s1 {font-kerning: none}</style>Hi all,


I have been trying to record a macro (I'm not at the point where I understand how to edit VBA I'm afraid), which I can use to clean up data that is exported from the tills in my business as a csv file into something that my bookkeeper can understand and upload to my accounts software. Here's a screenshot of what it currently generates (yuk!):


https://www.dropbox.com/s/a0q4kh2tbo9ab4n/Screen Shot 2017-05-02 at 21.19.07.png?dl=0


I had my macro working OK for a full week's worth of data. The problem I have hit is that I need my macro to delete a certain number of rows of unnecessary data, and the number of rows generated in the report changes depending on how many days it covers. In the example above it is the 8 rows with data in on the left that start with "Uni". However, this ranges from between 3 and 21 rows.


I have recorded it in two sections. The problem is in the first section, and the code I have so far is as follows:


Sub Clean_WSOB_2017()
'
' Clean_WSOB_2017 Macro
'


'
Range("1:1,3:3,4:4,7:7").Select
Range("A7").Activate
Selection.Delete Shift:=xlUp
Range("A1:A2").Select
Selection.Cut
Range("I1").Select
ActiveSheet.Paste
Columns("A:H").Select
Selection.Delete Shift:=xlToLeft
Rows("4:22").Select
Selection.Delete Shift:=xlUp
Columns("A:A").EntireColumn.AutoFit
Columns("B:B").EntireColumn.AutoFit
Range("D:D,E:E,F:F,I:I,K:K,M:M,O:O").Select
Range("O1").Activate
Selection.Delete Shift:=xlToLeft
Columns("C:C").Select
Selection.Insert Shift:=xlToRight
Columns("E:E").Select
Selection.Cut
Columns("C:C").Select
ActiveSheet.Paste
Columns("C:C").EntireColumn.AutoFit
Columns("D:D").Select
Selection.Cut
Columns("E:E").Select
ActiveSheet.Paste
Range("D5").Select
Selection.FormulaR1C1 = "=RC[2]+RC[3]"
Selection.AutoFill Destination:=Range("D5:D19"), Type:=xlFillDefault
Range("D5:D19").Select
Range("D4").Select
ActiveCell.FormulaR1C1 = "Payments Value"
Range("E4").Select
ActiveCell.FormulaR1C1 = "Float"
Range("F4").Select
ActiveCell.FormulaR1C1 = "Value @ Declaration"
Range("G4").Select
ActiveCell.FormulaR1C1 = "Paid Out"
Range("H4").Select
ActiveCell.FormulaR1C1 = "Variance"
Range("I4").Select
ActiveCell.FormulaR1C1 = "Declared Value"
Columns("H:H").Select
Selection.ClearFormats
Selection.NumberFormat = "$#,##0.00"
Range("D4:I4").Select
Selection.Font.Bold = True
With Selection
.HorizontalAlignment = xlGeneral
.VerticalAlignment = xlCenter
.WrapText = False
.Orientation = 0
.AddIndent = False
.IndentLevel = 0
.ShrinkToFit = False
.ReadingOrder = xlContext
.MergeCells = False
End With
With Selection
.HorizontalAlignment = xlCenter
.VerticalAlignment = xlCenter
.WrapText = False
.Orientation = 0
.AddIndent = False
.IndentLevel = 0
.ShrinkToFit = False
.ReadingOrder = xlContext
.MergeCells = False
End With
With Selection
.HorizontalAlignment = xlCenter
.VerticalAlignment = xlCenter
.WrapText = True
.Orientation = 0
.AddIndent = False
.IndentLevel = 0
.ShrinkToFit = False
.ReadingOrder = xlContext
.MergeCells = False
End With
Columns("D:I").Select
Selection.ColumnWidth = 12.14
Range("K5").Select
ActiveCell.FormulaR1C1 = "Monday"
Range("K6").Select
ActiveCell.FormulaR1C1 = "Tuesday"
Range("K7").Select
ActiveCell.FormulaR1C1 = "Wednesday"
Range("K8").Select
ActiveCell.FormulaR1C1 = "Thursday"
Range("K9").Select
ActiveCell.FormulaR1C1 = "Friday"
Range("K10").Select
ActiveCell.FormulaR1C1 = "Saturday"
Range("K11").Select
ActiveCell.FormulaR1C1 = "Sunday"
Columns("K:K").Select
Columns("K:K").EntireColumn.AutoFit
ActiveWindow.SmallScroll ToRight:=1
Range("D4:I4").Select
Selection.Copy
Range("L4").Select
ActiveSheet.Paste
Columns("L:Q").Select
Selection.ColumnWidth = 12.14
Range("L5").Select
Application.CutCopyMode = False
Selection.FormulaR1C1 = "=SUMIF(C2,RC11,C[-8])"
Selection.AutoFill Destination:=Range("L5:L11")
Range("L5:L11").Select
Selection.NumberFormat = "$#,##0.00"
Selection.Copy
Range("N5").Select
ActiveSheet.Paste
ActiveWindow.SmallScroll ToRight:=4
Range("M5:Q11").Select
Application.CutCopyMode = False
Selection.NumberFormat = "$#,##0.00"
Range("M5").Select
Selection.FormulaR1C1 = "=VLOOKUP(RC[-2],C2,4,0)"
ActiveCell.FormulaR1C1 = ""
Range("M6").Select
End Sub


I've highlighted the bit that deletes the rows for me in red.


I assume I should be able to insert some code in here to detect the number of rows that contain data in Column A from Row 8 down (the top part of the file never changes). I just have no clue as to where to start!


Many thanks in advance if anyone can help me.


Lou
 

Excel Facts

Does the VLOOKUP table have to be sorted?
No! when you are using an exact match, the VLOOKUP table can be in any order. Best-selling items at the top is actually the best.
Code cleaned up per below and changes re row deletion highlighted in red.
Step through the code via F8 to make sure the clean-up has been done properly.

Code:
Sub Clean_WSOB_2017()
[COLOR=#ff0000]Dim r%[/COLOR]
Range("1:1,3:3,4:4,7:7").Delete
Range("A1:A2").Cut Range("I1")
[COLOR=#ff0000]r = Cells(Rows.Count, 1).End(xlUp).Row[/COLOR]
[COLOR=#ff0000]Rows("4:" & r).Delete[/COLOR]
Columns("A:H").Delete
Columns("A:B").EntireColumn.AutoFit
Range("D:F,I:I,K:K,M:M,O:O").Delete
Columns("C:C").Insert
Columns("E:E").Cut Columns("C:C")
Columns("C:C").EntireColumn.AutoFit
Columns("D:D").Cut Columns("E:E")
Range("D5:D19").FormulaR1C1 = "=RC[2]+RC[3]"
Range("D4") = "Payments Value"
Range("E4") = "Float"
Range("F4") = "Value @ Declaration"
Range("G4") = "Paid Out"
Range("H4") = "Variance"
Range("I4") = "Declared Value"
Range("K5") = "Monday"
Range("K6") = "Tuesday"
Range("K7") = "Wednesday"
Range("K8") = "Thursday"
Range("K9") = "Friday"
Range("K10") = "Saturday"
Range("K11") = "Sunday"
Range("H:H,M5:Q11").NumberFormat = "$#,##0.00"
Range("D:I,L:Q").ColumnWidth = 12.14
Columns("K:K").EntireColumn.AutoFit
With Range("D4:I4")
    .Font.Bold = True
    .Copy Range("L4")
End With
With Range("L5:L11")
    .FormulaR1C1 = "=SUMIF(C2,RC11,C[-8])"
    .NumberFormat = "$#,##0.00"
    .Copy Range("N5")
End With
Range("M6").Select
End Sub
 
Upvote 0
That is absolutely brilliant - got it working this morning much to the relief of my bookkeeper, thank you so much!

And once you clear out all the gubbins generated from recording it, it's actually quite simple to understand what each line is doing.

Many, many thanks for taking the time to do this and averting a BIG headache :)

Lou
 
Upvote 0

Forum statistics

Threads
1,215,292
Messages
6,124,094
Members
449,142
Latest member
championbowler

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