Autofill VBA

adu_aks

New Member
Joined
Sep 30, 2009
Messages
5
Hello everyone.

I'm trying to automate Excel's autofill feature for attached Spreadsheet (As-is) so I can use a Pivot table to summarize my data. See link for TO-BE Spreadsheet.

I don't even know where to start, so any help would be much appreciated. At the moment, I'm double-clicking the bottom right corner of each cell to get the cells below to autopopulate.

AS-IS
PART_ID</SPAN>LOT_SERIAL_ID</SPAN>EXPIRATION_DATE</SPAN>AVAIL_QTY</SPAN>AVAIL_HOLD_QTY</SPAN>
005557731104</SPAN>
20130502</SPAN>2013-11-28</SPAN>1620</SPAN>0</SPAN>
005557731176</SPAN>
20130110</SPAN>2013-08-08</SPAN>68</SPAN>0</SPAN>
20130305</SPAN>2013-10-01</SPAN>216</SPAN>0</SPAN>
005557731278</SPAN>
20130613</SPAN>2014-01-09</SPAN>2880</SPAN>0</SPAN>
005557740042</SPAN>
20130116</SPAN>2013-11-17</SPAN>15</SPAN>0</SPAN>
20130326</SPAN>2014-01-25</SPAN>54</SPAN>0</SPAN>
20130327</SPAN>2014-01-26</SPAN>180</SPAN>0</SPAN>
20130526</SPAN>2014-03-27</SPAN>120</SPAN>0</SPAN>
005557742061</SPAN>
20121222</SPAN>2013-07-20</SPAN>18</SPAN>0</SPAN>
20130312</SPAN>2013-10-08</SPAN>270</SPAN>0</SPAN>
005557742062</SPAN>
20121218</SPAN>2013-07-16</SPAN>540</SPAN>0</SPAN>
005557742063</SPAN>
20130215</SPAN>2013-09-13</SPAN>198</SPAN>0</SPAN>
20130312</SPAN>2013-10-08</SPAN>180</SPAN>0</SPAN>
20130327</SPAN>2013-10-23</SPAN>180</SPAN>0</SPAN>

<TBODY>
</TBODY><COLGROUP><COL><COL><COL><COL><COL></COLGROUP>

TO-BE

PART_ID</SPAN>LOT_SERIAL_ID</SPAN>EXPIRATION_DATE</SPAN>AVAIL_QTY</SPAN>AVAIL_HOLD_QTY</SPAN>
005557731104</SPAN>
005557731104</SPAN>20130502</SPAN>2013-11-28</SPAN>1620</SPAN>0</SPAN>
005557731176</SPAN>
005557731176</SPAN>20130110</SPAN>2013-08-08</SPAN>68</SPAN>0</SPAN>
005557731176</SPAN>20130305</SPAN>2013-10-01</SPAN>216</SPAN>0</SPAN>
005557731278</SPAN>
005557731278</SPAN>20130613</SPAN>2014-01-09</SPAN>2880</SPAN>0</SPAN>
005557740042</SPAN>
005557740042</SPAN>20130116</SPAN>2013-11-17</SPAN>15</SPAN>0</SPAN>
005557740042</SPAN>20130326</SPAN>2014-01-25</SPAN>54</SPAN>0</SPAN>
005557740042</SPAN>20130327</SPAN>2014-01-26</SPAN>180</SPAN>0</SPAN>
005557740042</SPAN>20130526</SPAN>2014-03-27</SPAN>120</SPAN>0</SPAN>
005557742061</SPAN>
005557742061</SPAN>20121222</SPAN>2013-07-20</SPAN>18</SPAN>0</SPAN>
005557742061</SPAN>20130312</SPAN>2013-10-08</SPAN>270</SPAN>0</SPAN>
005557742062</SPAN>
005557742062</SPAN>20121218</SPAN>2013-07-16</SPAN>540</SPAN>0</SPAN>
005557742063</SPAN>
005557742063</SPAN>20130215</SPAN>2013-09-13</SPAN>198</SPAN>0</SPAN>
005557742063</SPAN>20130312</SPAN>2013-10-08</SPAN>180</SPAN>0</SPAN>
005557742063</SPAN>20130327</SPAN>2013-10-23</SPAN>180</SPAN>0</SPAN>

<TBODY>
</TBODY><COLGROUP><COL><COL><COL><COL><COL></COLGROUP>
 

Excel Facts

Difference between two dates
Secret function! Use =DATEDIF(A2,B2,"Y")&" years"&=DATEDIF(A2,B2,"YM")&" months"&=DATEDIF(A2,B2,"MD")&" days"
this should do

Code:
Sub convert()
lr = Range("B" & Rows.Count).End(xlUp).Row
For Each cell In Range("A2:A" & lr)
If cell <> "" And cell.Offset(1, 0) = "" Then
  cell.Offset(1, 0) = cell
 End If
Next cell
For i = 2 To lr
 If Cells(i, "B") = "" Then Cells(i, "B").EntireRow.Delete
 Next i
End Sub
 
Upvote 0
This is perfect. Love the simplicity of the code. Thanks a bunch hippiehacker!

this should do

Code:
Sub convert()
lr = Range("B" & Rows.Count).End(xlUp).Row
For Each cell In Range("A2:A" & lr)
If cell <> "" And cell.Offset(1, 0) = "" Then
  cell.Offset(1, 0) = cell
 End If
Next cell
For i = 2 To lr
 If Cells(i, "B") = "" Then Cells(i, "B").EntireRow.Delete
 Next i
End Sub
 
Upvote 0
@hippiehacker: could you please recommend how to best automate the "Convert To Number" option that's provided when you select column A data.

The code i'm using (see below) works perfectly but I'm wondering if there's a more simple way to do this.

https://www.dropbox.com/s/qtgj53x4f1boe8x/Microsoft Excel - Daily_inv.jpg

[/HTML]
Code:
Sub sku()
Application.ScreenUpdating = False
counter = 2
Do Until ThisWorkbook.Sheets("Sheet1").Range("B" & counter).Value = ""
    Range("G" & counter).Select
    ActiveCell.FormulaR1C1 = "=RC[-6]*1"
    
counter = counter + 1
Loop
Range("G2:G" & counter).Select
Selection.Copy
Range("A2").Select
Selection.PasteSpecial Paste:=xlPasteValues, Operation:=xlNone, SkipBlanks _
        :=False, Transpose:=False
Application.CutCopyMode = False

Range("G2:G" & counter).Select
Selection.Delete
Range("A1").Select
 
End Sub
 
Upvote 0
this code should convert text to numbers on activesheet

Code:
With ActiveSheet.UsedRange
    .Value = Evaluate(.Address & "*1")
End With
 
Upvote 0
Thank you hippiehacker. The code above works great except that it affects the text cells in my activesheet as well. I've tried modifying the code with "With ActiveSheet.Selection". No luck.
 
Upvote 0
Thank you hippiehacker. The code above works great except that it affects the text cells in my activesheet as well. I've tried modifying the code with "With ActiveSheet.Selection". No luck.


without activesheet should do

Code:
With Selection
    .Value = Evaluate(.Address & "*1")
End With
 
Upvote 0

Forum statistics

Threads
1,213,492
Messages
6,113,967
Members
448,537
Latest member
Et_Cetera

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