Copy & Paste based on conditions

BlairClark

New Member
Joined
Mar 23, 2019
Messages
4
Hi,
I'm trying to create a macro that looks up the word "Insert" in column E2, copies the contents from A2:G20 and pastes in the row directly below (A3:G21). I'm hoping to loop the macro because there's the possibility that more rows need the same argument.
ABCDEFG
1SKUDescriptionStartEndCommentsHoursCases
21001LB 12x33025/03/19 05:3026/03/19 02:30Insert3000
31003LB 24x33026/03/19 03:3026/03/19 22:002579
41010LR 12x33026/03/19 23:0027/03/19 19:30Insert5000
51011LR 24x33027/03/19 20:3028/03/19 16:00Insert5000
61009ST 12x33028/03/19 17:0028/03/19 23:002000
71008ST 24x33029/03/19 00:0029/03/19 20:004000
81007SP 12x33029/03/19 21:0030/03/19 04:00Insert3790
91006SP 24x33030/03/19 05:0030/03/19 18:003330

<tbody>
</tbody>

Any help would be appreciated.

Blair
 

Some videos you may like

Excel Facts

Spell Check in Excel
Press F7 to start spell check in Excel. Be careful, by default, Excel does not check Capitalized Werds (whoops)

James006

Well-known Member
Joined
Apr 4, 2009
Messages
3,680
Hi,

You can test following macro :

Code:
Sub CopyRowsWithCondition()
' If Cell in E Column = Insert or Copy
Dim i As Long
Dim arCrit As Variant
Dim arVal As Variant


Application.DisplayAlerts = False
arCrit = Array("Insert", "Copy")
' Adjust your tab Name
With Worksheets("Sheet2")
  For i = 100 To 2 Step -1
    For Each arVal In arCrit
      If InStr(1, .Range("E" & i).Value, arVal) >= 1 Then
          .Rows(i + 1).Insert
          .Range("A" & i & ":G" & i).Copy Destination:=Range("A" & i + 1)
      End If
    Next arVal
  Next i
End With
Application.DisplayAlerts = True


End Sub

Hope this will help
 

BlairClark

New Member
Joined
Mar 23, 2019
Messages
4
Thanks James006 (should be 007).
This works brilliantly.

One more question... Is there a way once the above macro has been run to change the dates in column C & D. This is a production schedule and I need to find out how much of something we produce on any given day. As you can see, all the insert rows are items that run over multiple days i.e. Row 2 - 25/03/19 05:30 to 26/03/19 02:30. Once your macro runs I need to change the original end to represent the start date but for a time prior to midnight (End will become 25/03/19 23:59 in Row 2). The inserted row will in turn have a different start time - 26/03/19 00:00.

Is this possible?
 

James006

Well-known Member
Joined
Apr 4, 2009
Messages
3,680
Glad to hear macro is helping you out ... :)

What are precisely the rules for Start and End fields for any newly inserted row ???
 

BlairClark

New Member
Joined
Mar 23, 2019
Messages
4

ADVERTISEMENT

Every copied row needs the end (Column D) changed to 23:59 on the same date as the start column.
Every inserted row needs the start (Column C) changed to 00:00 on the same date as the end column.

Original example below:
A2 - 1001
B2 - LB 12x330
C2 - 25/03/19 05:30D3 - 26/03/19 02:30
E2 - Insert
F2 -
G2 - 3000

Requirements after CopyRowsWithCondition macro
A2 - 1001
B2 - LB 12x330
C2 - 25/03/19 05:30
D2 - 25/03/19 23:59

E2 - Insert
F2 -
G2 - 3000

A3 - 1001
B3 - LB 12x330
C3 - 26/03/19 00:00
D3 - 26/03/19 02:30
E3 - Insert
F3 -
G3 - 3000

I hope this makes sense?
 

James006

Well-known Member
Joined
Apr 4, 2009
Messages
3,680
Brilliant Explanation ... !!! :)

Are you a Teacher or an Instructor ... ???

If not ... it is a shame ... you do have a real talent for exposing issues ... :cool:
 

James006

Well-known Member
Joined
Apr 4, 2009
Messages
3,680

ADVERTISEMENT

Thanks to your Great explanation ....

the modiifications were dead simple to implement ...

Code:
Sub CopyRowsWithCondition()
' If Cell in E Column = Insert or Copy
Dim i As Long
Dim arCrit As Variant
Dim arVal As Variant


arCrit = Array("Insert", "Copy")
' Adjust your tab Name
With Worksheets("Sheet1")
  For i = 10 To 2 Step -1
    For Each arVal In arCrit
      If InStr(1, .Range("E" & i).Value, arVal) >= 1 Then
          .Rows(i + 1).Insert
          .Range("A" & i & ":G" & i).Copy Destination:=Range("A" & i + 1)
          ' Copied is identified with i
          .Range("D" & i).Value = Int(.Range("C" & i).Value) + 0.999305
          ' Inserted is identified with i + 1
          .Range("C" & i + 1).Value = Int(.Range("D" & i + 1).Value)
      End If
    Next arVal
  Next i
End With


End Sub

Hope this in line with your expectations ...

P.S. by the way ... don't you need the E Column to be completely cleared of the "Insert" comment ... once the macro is over ... ???
 
Last edited:

BlairClark

New Member
Joined
Mar 23, 2019
Messages
4
Wow!

You've exceeded my expectations... this works brilliantly. I wish I was at the level you're at... clearing the "insert" is right up my alley :)

There's potentially more to come too... for now, you've been a lifesaver.

For a brewery scheduler this is magic. Thanks heaps @James006.
 

Watch MrExcel Video

Forum statistics

Threads
1,108,791
Messages
5,524,897
Members
409,610
Latest member
db321

This Week's Hot Topics

Top