Macro To Compare and Insert Rows

wayneeswif

New Member
Joined
Apr 23, 2011
Messages
2
I am hopeful that someone can help me with writing a macro that will compare row headers in Column A between a master worksheet (Year) and another worksheet (1st Qtr) and insert blank rows at each point where a row header is in Year but not in 1st Qtr. There will not be blank rows amongst the row headers before the macro is run. The number of rows to compare varies; the stopping point is the first empty cell in Column A in Year. There will be data in Columns B, etc that needs to be shifted down at the insertion of each blank row. I am using Windows 7, Excel 2010. I have not been able to create a macro that even remotely works and have not been able to find any scenarios that are close of enough to mine to tweak.

An example of the Column A data and what I need is:
<table border="0" cellpadding="0" cellspacing="0" width="437"><col style="width: 27pt;" width="36"> <col style="width: 80pt;" width="106"> <col style="width: 79pt;" width="105"> <col style="width: 143pt;" width="190"> <tbody><tr style="height: 15pt;" height="20"> <td style="height: 15pt; width: 27pt;" align="center" width="36" height="20">
</td> <td class="xl68" style="width: 80pt;" align="center" width="106">1st Qtr (before)</td> <td class="xl68" style="width: 79pt;" align="center" width="105">Year (master)</td> <td class="xl68" style="width: 143pt;" align="center" width="190">1st Qtr (after running macro)</td> </tr> <tr style="height: 15pt;" height="20"> <td class="xl66" style="height: 15pt;" align="center" height="20">Row</td> <td class="xl66" align="center">Column A</td> <td class="xl66" align="center">Column A</td> <td class="xl66" align="center">Column A</td> </tr> <tr style="height: 15pt;" height="20"> <td class="xl67" style="height: 15pt;" align="center" height="20">1</td> <td class="xl67" align="center">AL UI</td> <td class="xl67" align="center">AL UI</td> <td class="xl67" align="center">AL UI</td> </tr> <tr style="height: 15pt;" height="20"> <td class="xl67" style="height: 15pt;" align="center" height="20">2</td> <td class="xl67" align="center">CA UI</td> <td class="xl67" align="center">AZ UI</td> <td class="xl67" align="center">
</td> </tr> <tr style="height: 15pt;" height="20"> <td class="xl67" style="height: 15pt;" align="center" height="20">3</td> <td class="xl67" align="center">CO UI</td> <td class="xl67" align="center">CA UI</td> <td class="xl67" align="center">CA UI</td> </tr> <tr style="height: 15pt;" height="20"> <td class="xl67" style="height: 15pt;" align="center" height="20">4</td> <td class="xl67" align="center">NM UI</td> <td class="xl67" align="center">CO UI</td> <td class="xl67" align="center">CO UI</td> </tr> <tr style="height: 15pt;" height="20"> <td class="xl67" style="height: 15pt;" align="center" height="20">5</td> <td class="xl67" align="center">NV UI</td> <td class="xl67" align="center">IL UI</td> <td class="xl67" align="center">
</td> </tr> <tr style="height: 15pt;" height="20"> <td class="xl67" style="height: 15pt;" align="center" height="20">6</td> <td class="xl67" align="center">
</td> <td class="xl67" align="center">NJ UI</td> <td class="xl67" align="center">
</td> </tr> <tr style="height: 15pt;" height="20"> <td class="xl67" style="height: 15pt;" align="center" height="20">7</td> <td class="xl67" align="center">
</td> <td class="xl67" align="center">NM UI</td> <td class="xl67" align="center">NM UI</td> </tr> <tr style="height: 15pt;" height="20"> <td class="xl67" style="height: 15pt;" align="center" height="20">8</td> <td class="xl67" align="center">
</td> <td class="xl67" align="center">NV UI</td> <td class="xl67" align="center">NV UI</td> </tr> </tbody></table>
 

Excel Facts

What do {} around a formula in the formula bar mean?
{Formula} means the formula was entered using Ctrl+Shift+Enter signifying an old-style array formula.
Welcome to the MrExcel board!

Test this in a copy of your workbook.

<font face=Courier New><br><SPAN style="color:#00007F">Sub</SPAN> InsertRowsQ1()<br>    <SPAN style="color:#00007F">Dim</SPAN> wsQ1 <SPAN style="color:#00007F">As</SPAN> Worksheet, wsY <SPAN style="color:#00007F">As</SPAN> Worksheet<br>    <SPAN style="color:#00007F">Dim</SPAN> rws <SPAN style="color:#00007F">As</SPAN> <SPAN style="color:#00007F">Long</SPAN>, Yrow <SPAN style="color:#00007F">As</SPAN> <SPAN style="color:#00007F">Long</SPAN>, Qrow <SPAN style="color:#00007F">As</SPAN> <SPAN style="color:#00007F">Long</SPAN>, i <SPAN style="color:#00007F">As</SPAN> <SPAN style="color:#00007F">Long</SPAN><br>    <SPAN style="color:#00007F">Dim</SPAN> ary<br>    <br>    <SPAN style="color:#00007F">Set</SPAN> wsQ1 = Sheets("1st Qtr")<br>    <SPAN style="color:#00007F">Set</SPAN> wsY = Sheets("Year")<br>    Application.ScreenUpdating = <SPAN style="color:#00007F">False</SPAN><br>    <SPAN style="color:#00007F">With</SPAN> wsQ1<br>        ary = .Range("A1", .Range("A" & .Rows.Count).End(xlUp)).Value<br>        <SPAN style="color:#00007F">For</SPAN> i = 1 <SPAN style="color:#00007F">To</SPAN> <SPAN style="color:#00007F">UBound</SPAN>(ary, 1)<br>            Qrow = wsQ1.Columns("A").Find(What:=ary(i, 1), _<br>                LookAt:=xlWhole, MatchCase:=False, SearchFormat:=False).Row<br>            Yrow = wsY.Columns("A").Find(What:=ary(i, 1), _<br>                LookAt:=xlWhole, MatchCase:=False, SearchFormat:=False).Row<br>            rws = Yrow - Qrow<br>            <SPAN style="color:#00007F">If</SPAN> rws > 0 <SPAN style="color:#00007F">Then</SPAN><br>                .Rows(Qrow).Resize(rws).Insert<br>            <SPAN style="color:#00007F">End</SPAN> <SPAN style="color:#00007F">If</SPAN><br>        <SPAN style="color:#00007F">Next</SPAN> i<br>    <SPAN style="color:#00007F">End</SPAN> <SPAN style="color:#00007F">With</SPAN><br>    Application.ScreenUpdating = <SPAN style="color:#00007F">True</SPAN><br><SPAN style="color:#00007F">End</SPAN> <SPAN style="color:#00007F">Sub</SPAN><br></FONT>
 
Upvote 0

Forum statistics

Threads
1,224,574
Messages
6,179,633
Members
452,933
Latest member
patv

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