Row archived, moves it to another tab

MOB

Well-known Member
Joined
Oct 18, 2005
Messages
1,056
Office Version
  1. 365
Platform
  1. Windows
Someone has asked if the following is possible;

- Rows of data in excel
- when a row is "archived" it moves that row to another "archived" tab, below existing data
- the "archived" tab therefore grows as rows move across over time
- the original now-blank rows get deleted

They initially said that conditional formatting should drive the event it but I think that a Y/N somewhere would be a better trigger?

Does anyone have any similar spreadsheet ideas that would work?

TIA
 

Excel Facts

Copy formula down without changing references
If you have =SUM(F2:F49) in F50; type Alt+' in F51 to copy =SUM(F2:F49) to F51, leaving the formula in edit mode. Change SUM to COUNT.
This is certainly possible, and should be fairly easy/straightforward provided you can tell us the conditions on when a row show be archived.
You mention Conditional Formatting. What is the rule? That rule is probably the same one we can use to determine what rows to archive.
 
Upvote 0
1. Condtional Formatting formats a cell based on a condtion ONLY. It does not affect other data in any way.

2. Formulas can netiher move nor delete cells data.

3. You need VBA to delete cells.

This is looking like a VBA solution to me of which I'm not an expert.
 
Last edited:
Upvote 0
This is certainly possible, and should be fairly easy/straightforward provided you can tell us the conditions on when a row show be archived.
You mention Conditional Formatting. What is the rule? That rule is probably the same one we can use to determine what rows to archive.

I think the best solution is to have a column, say "P" with the heading "Archive?" that when YES is entered in a row, the code executes. I cant really see the value in using conditional formatting for this?
 
Upvote 0
I think the best solution is to have a column, say "P" with the heading "Archive?" that when YES is entered in a row, the code executes. I cant really see the value in using conditional formatting for this?
I never said that you should use Conditional Formatting for this.

You initially said:
They initially said that conditional formatting should drive the event it but I think that a Y/N somewhere would be a better trigger?
The fact that the said that they wanted "Conditional Formatting" to drive the event seems to imply that there is some manually to automatically determine which rows should be moved, without the need to manually update some "trigger" column. Conditional Formatting runs off of some "trigger", which is a Condition or formula. We may be able to use that same rule/condition in our VBA code so you wouldn't need to manually create a column to tell it which rows to archive.

So what then, exactly, is that condition/rule?

We can certainly have VBA run off of some column that you manually update, but if there is a way to determine it automatically, why add extra manual work for yourself?
 
Upvote 0
If you really want to use column marked "YES" for the rows to delete, here is code that will do that. It uses filters instead of loops, as loops are much more inefficient (run slower).
Just change the names of your sheets to match:
Code:
Sub MyArchiveMacro()

    Dim dataWS As Worksheet
    Dim arcWS As Worksheet
    Dim lrd As Long
    Dim lra As Long
    Dim rng As Range
    Dim rng2 As Range
    
    Application.ScreenUpdating = False
    
'   Set data sheet and archive sheet
    Set dataWS = Sheets("Sheet1")
    Set arcWS = Sheets("Archived")
    
'   Find last row with data on archive sheet (by looking for data in column A)
    lra = arcWS.Cells(Rows.Count, "A").End(xlUp).Row
    
'   Find last row with data in column P on data sheet
    dataWS.Activate
    lrd = Cells(Rows.Count, "P").End(xlUp).Row
    
'   Filter data to only show rows to archive (column P = "YES")
    Set rng = Range("A1:P" & lrd)
    rng.AutoFilter
    rng.AutoFilter Field:=16, Criteria1:="YES"
'   Get range to copy without header row
    Set rng2 = Intersect(Range("A2:P" & lrd), rng.SpecialCells(xlCellTypeVisible))
'   Copy filtered data
    rng2.Copy
    
'   Paste data into first available row on archive sheet
    Sheets("Archived").Select
    Range("A" & lra + 1).Select
    ActiveSheet.Paste
    Application.CutCopyMode = False

'   Go back to data sheet and delete data just copied
    dataWS.Activate
    Application.DisplayAlerts = False
    rng2.Delete
    Application.DisplayAlerts = True

'   Remove filters to show all data
    Cells.AutoFilter
    
    Application.ScreenUpdating = True
    
End Sub
 
  • Like
Reactions: MOB
Upvote 0
Many thanks, that works nicely
 
Upvote 0

Forum statistics

Threads
1,216,081
Messages
6,128,695
Members
449,464
Latest member
againofsoul

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