Tables: Cut & Paste Automatically - Value driven code

ktobiano

New Member
Joined
Jul 6, 2004
Messages
8
Quote requests come in and I record them in a table.

Based on the "status" cell, I need specific rows to automatically move to the appropriate table on a different sheet for another department to work on.

I looked up some code to move an entire row to the correct sheet based on the status cell value, but it pasted the data BELOW the actual table instead of inserting a new table row and then pasting the data.

To keep it simple here are 4 of my columns
Date, Name, ID, Status

Here are my sheet/table names:
Quote, FollowUp, Awarded, Lost

This spreadsheet can get very large very quick so I'd prefer a simple code that didn't eat up resources.

Any help is GREATLY appreciated. I am not great at VBA - know just enough to be dangerous.
 

Excel Facts

Ambidextrous Undo
Undo last command with Ctrl+Z or Alt+Backspace. If you use the Undo icon in the QAT, open the drop-down arrow to undo up to 100 steps.
Maybe try playing around with something along the lines of this
Code:
Private Sub Worksheet_Change(ByVal Target As Range)

    Dim TblQ As ListObject, DestTbl As ListObject
    Dim LstRow As Long
    Dim NewRow As ListRow

Set TblQ = ListObjects("Quote")

'limit to single cell
If Target.Count > 1 Then Exit Sub
'limit to 4th column
If Intersect(Target, TblQ.ListColumns(4).DataBodyRange) Is Nothing Then
    Exit Sub
Else
    'the table row to move
    LstRow = TblQ.ListRows(Target.Row - TblQ.HeaderRowRange.Row).Index
    'where to move it
    If UCase(Target) = "F" Then Set DestTbl = Sheets("FollowUP").ListObjects("FollowUP")
    If UCase(Target) = "A" Then Set DestTbl = Sheets("Awarded").ListObjects("Awarded")
    If UCase(Target) = "L" Then Set DestTbl = Sheets("Lost").ListObjects("Lost")
   'insert table row
    Set NewRow = DestTbl.ListRows.Add(AlwaysInsert:=True)
    'populate it
    NewRow.Range.Cells(1, 1).Resize(, 4).Value = TblQ.ListRows(LstRow).Range.Value
    'remove original
    Application.EnableEvents = False
    TblQ.ListRows(LstRow).Delete
    Application.EnableEvents = True
End If
End Sub

A couple of references
The VBA Guide To ListObject Excel Tables — The Spreadsheet Guru
Excel: Working with Tables (VBA)

Good luck
 
Upvote 0

Forum statistics

Threads
1,223,911
Messages
6,175,329
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