Parse Data - Paste Range to new sheets as values only.

Scifo

New Member
Joined
Apr 16, 2023
Messages
9
Office Version
  1. 365
Platform
  1. Windows
Hi,

I took the following code from a forum, I have alreadly kindly had problem solved on this forum and have managed to come up with some solutions to others (though I am very new to Macros).

The Macro is to take data (weekly) and seperate it based on matching the name in Column 2.
Sheet 1 is where the data is input. There are simple formulas in Column 1 (A) and and also in columns 9/10. Which would be updated weekly.

The Problem: I need to copy the data (particularly) from Column A in the new sheets as Values (without the formulas).
I believe this is the code that needs to be changed.
VBA Code:
SHEET_EXISTS:
        ws.Range("A" & titlerow & ":M" & lr).Offset(1).Copy Sheets(myarr(i) & "").Range("A" & Rows.Count).End(xlUp).Offset(1)

I have tried adding to Copy Range & PasteValues in this line of code but to no avail.


I have added the copy Rows/Range - Paste.Vaules in earlier parts of the code which kind of works but changes either removes the formulas in the Sheet 1 or for some reason doubles the formulas (formula) + (ormula)
Would be grateful for any more advice.

Here is the total code just in Case

VBA Code:
Sub parse_data()
Dim lr As Long
Dim ws As Worksheet
Dim vcol, i As Integer
Dim icol As Long
Dim myarr As Variant
Dim title As String
Dim titlerow As Integer
 Range("B2:H150").Select
    Selection.replace What:="/", Replacement:=" ", LookAt:=xlPart, _
        SearchOrder:=xlByRows, MatchCase:=False, SearchFormat:=False, _
        ReplaceFormat:=False, FormulaVersion:=xlReplaceFormula2
         Selection.replace What:="in which half more goal?", Replacement:="In Which half most Goals", LookAt:=xlPart, _
        SearchOrder:=xlByRows, MatchCase:=False, SearchFormat:=False, _
        ReplaceFormat:=False, FormulaVersion:=xlReplaceFormula2
        Selection.replace What:="Combo Doppia Chance & Multigoal Extra", Replacement:="Combo DC & Multigoal Exta", LookAt:=xlPart, _
        SearchOrder:=xlByRows, MatchCase:=False, SearchFormat:=False, _
        ReplaceFormat:=False, FormulaVersion:=xlReplaceFormula2
        Selection.replace What:="Team to Score", Replacement:="Teams Score", LookAt:=xlPart, _
        SearchOrder:=xlByRows, MatchCase:=False, SearchFormat:=False, _
        ReplaceFormat:=False, FormulaVersion:=xlReplaceFormula2
        Selection.replace What:="halftime", Replacement:="HT", LookAt:=xlPart, _
        SearchOrder:=xlByRows, MatchCase:=False, SearchFormat:=False, _
        ReplaceFormat:=False, FormulaVersion:=xlReplaceFormula2
        Selection.replace What:="Under/Over", Replacement:="U-O", LookAt:=xlPart, _
        SearchOrder:=xlByRows, MatchCase:=False, SearchFormat:=False, _
        ReplaceFormat:=False, FormulaVersion:=xlReplaceFormula2
        Selection.replace What:="Under Over", Replacement:="U-O", LookAt:=xlPart, _
        SearchOrder:=xlByRows, MatchCase:=False, SearchFormat:=False, _
        ReplaceFormat:=False, FormulaVersion:=xlReplaceFormula2
        Selection.replace What:="half time", Replacement:="HT", LookAt:=xlPart, _
        SearchOrder:=xlByRows, MatchCase:=False, SearchFormat:=False, _
        ReplaceFormat:=False, FormulaVersion:=xlReplaceFormula2
        Selection.replace What:="americanfootball", Replacement:="american football ", LookAt:=xlPart, _
        SearchOrder:=xlByRows, MatchCase:=False, SearchFormat:=False, _
        ReplaceFormat:=False, FormulaVersion:=xlReplaceFormula2
        Selection.replace What:="tabletennis", Replacement:="table tennis", LookAt:=xlPart, _
        SearchOrder:=xlByRows, MatchCase:=False, SearchFormat:=False, _
        ReplaceFormat:=False, FormulaVersion:=xlReplaceFormula2
       
        
'Filtered Column Number
vcol = 2
'Worksheet to be split
Set ws = Sheets("Sheet1")
lr = ws.Cells(ws.Rows.Count, vcol).End(xlUp).Row
title = "A1:M1"
titlerow = ws.Range(title).Cells(1).Row
icol = ws.Columns.Count
ws.Cells(1, icol) = "Unique"
For i = 2 To lr
On Error Resume Next
If ws.Cells(i, vcol) <> "" And Application.WorksheetFunction.Match(ws.Cells(i, vcol), ws.Columns(icol), 0) = 0 Then
ws.Cells(ws.Rows.Count, icol).End(xlUp).Offset(1) = ws.Cells(i, vcol)
End If
Next
myarr = Application.WorksheetFunction.Transpose(ws.Columns(icol).SpecialCells(xlCellTypeConstants))
ws.Columns(icol).clear
  For i = 2 To UBound(myarr)
         ws.Range(title).AutoFilter field:=vcol, Criteria1:=myarr(i) & ""
 If Evaluate("=ISREF('" & myarr(i) & "'!A1)") Then GoTo SHEET_EXISTS
        If Not Evaluate("=ISREF('" & myarr(i) & "'!A1)") Then
            Sheets.Add(after:=Worksheets(Worksheets.Count)).Name = myarr(i) & ""
        Else
            Sheets(myarr(i) & "").Move after:=Worksheets(Worksheets.Count)
        End If
        ws.Range("A" & titlerow & ":A" & lr).EntireRow.Copy Sheets(myarr(i) & "").Range("A1")

GoTo NEW_SHEET
SHEET_EXISTS:
        ws.Range("A" & titlerow & ":M" & lr).Offset(1).Copy Sheets(myarr(i) & "").Range("A" & Rows.Count).End(xlUp).Offset(1)
NEW_SHEET:

      Sheets(myarr(i) & "").Columns.AutoFit
           If Sheet1.Range("r2").Value = 1 Then
    Application.Run ("Module2.Button4_Click")
    ElseIf Sheet1.Range("r2").Value < 1 Then
    End If
    
     

Next
'Remove filter
ws.AutoFilterMode = False
ws.Activate
End Sub
 

Excel Facts

Repeat Last Command
Pressing F4 adds dollar signs when editing a formula. When not editing, F4 repeats last command.
The part that pastes as values only is "xlPasteValues"

VBA Code:
Sub CopyVal()
    Range("A17:A25").Copy
    Windows("Book4").Activate
    Range("A7").Select
    Selection.PasteSpecial Paste:=xlPasteValues, Operation:=xlNone, SkipBlanks _
        :=False, Transpose:=False
End Sub
 
Upvote 0
Thank you for your reply.
Are you saying this should replace the line of code i highlighted or attached to it (posted below it)?
I had tried something similar to latter
 
Upvote 0
VBA Code:
SHEET_EXISTS:
        ws.Range("A" & titlerow & ":M" & lr).Offset(1).Copy Sheets(myarr(i) & "").Range("A" & Rows.Count).End(xlUp).Offset(1)

This is the copy side
 
Upvote 0
VBA Code:
On Error Resume Next
If ws.Cells(i, vcol) <> "" And Application.WorksheetFunction.Match(ws.Cells(i, vcol), ws.Columns(icol), 0) = 0 Then
ws.Cells(ws.Rows.Count, icol).End(xlUp).Offset(1) = ws.Cells(i, vcol)
End If


And this is the paste to different sheets side?
Thanks for your patience with my lack of knowledge.

I tried placing below the copy portion you identified and that ended up overwriting a summary sheet. (and changing the input page (sheet1) removing the formulas from there.
I had previously tried placing something similar but changes the input page
 

Attachments

  • sheet1.PNG
    sheet1.PNG
    35.8 KB · Views: 9
Upvote 0
unfortunately I couldn't get it to work in the desired way it ends up changing the input sheet
 
Upvote 0
Try:

VBA Code:
SHEET_EXISTS:
        ws.Range("A" & titlerow & ":M" & lr).Offset(1).Copy
        Sheets(myarr(i) & "").Range("A" & Rows.Count).End(xlUp).Offset(1).PasteSpecial Paste:=xlPasteValues
 
Upvote 0
Solution
Oh wow this seems to be working. Thanks very much.
I will do some more rigourous tests and confirm later

I thought I had tried all differing variations of a line similar to this but was not getting it quite right. ( some error expecting end of sub or somehting else)
Thanks again
 
Upvote 0
Just wanted to confirm that solution worked well.
So thanks again taking the time for both replies and of coures the solution
 
Upvote 0

Forum statistics

Threads
1,224,875
Messages
6,181,514
Members
453,050
Latest member
Obil

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