+ Reply to Thread
Results 1 to 5 of 5

ActiveSheet.Paste Link:= True Does Not Work After Awhile - 1004 MS Excel cannot paste data

Hybrid View

  1. #1
    Valued Forum Contributor tehneXus's Avatar
    Join Date
    04-12-2013
    Location
    Hamburg, Germany
    MS-Off Ver
    Work: MS-Office 2010 32bit @ Win8 32bit / Home: MS-Office 2016 32bit @ Win10 64bit
    Posts
    944

    Re: ActiveSheet.Paste Link:= True Does Not Work After Awhile - 1004 MS Excel cannot paste

    Hi,

    check if this works for you, sorry for changing so much but you had a lot of selects there: Sample Disposition 06-25-13_edit.xlsm

    contains:
    Option Explicit
    
    Sub Macro1()
        Dim xlWsSrc As Worksheet, xlWsNew As Worksheet
        Dim xlRng As Range
        Dim CoName As String
        Dim sgnStart As Single
        Dim LastRow As Long, RowNum As Long, CoRowNum As Long, i As Long
        Dim LastCol As Integer, Attempt As Integer, j As Integer
        
        On Error GoTo Macro1_ErrorHandler
        Application.ScreenUpdating = False
    
        Set xlWsSrc = Worksheets("Sheet1")
    
        ' Find last row for the loop.
        LastRow = GetLastRow(xlWsSrc)
    
        ' Find last column for the Disposition code.
        LastCol = GetLastCol(xlWsSrc)
    
        With xlWsSrc
            'data validation
            With Union(.Range(.Cells(2, LastCol + 1), .Cells(LastRow, LastCol + 1)), _
                              .Range(.Cells(2, LastCol + 4), .Cells(LastRow, LastCol + 4)), _
                              .Range(.Cells(2, LastCol + 7), .Cells(LastRow, LastCol + 7)), _
                              .Range(.Cells(2, LastCol + 10), .Cells(LastRow, LastCol + 10)), _
                              .Range(.Cells(2, LastCol + 13), .Cells(LastRow, LastCol + 13)), _
                              .Range(.Cells(2, LastCol + 16), .Cells(LastRow, LastCol + 16)), _
                              .Range(.Cells(2, LastCol + 19), .Cells(LastRow, LastCol + 19)), _
                              .Range(.Cells(2, LastCol + 22), .Cells(LastRow, LastCol + 22)), _
                              .Range(.Cells(2, LastCol + 25), .Cells(LastRow, LastCol + 25))).Validation
    
    
                .Delete
                .Add Type:=xlValidateList, AlertStyle:=xlValidAlertStop, Operator:=xlBetween, Formula1:="=dc"
                
            End With
    
            'borders:
            For j = 1 To 25 Step 3
                With .Range(.Cells(1, LastCol + j), .Cells(LastRow, LastCol + j + 2))
                    For i = 7 To 10
                        .Borders(i).Weight = xlThick
                    Next i
                End With
            Next j
    
            'headings
            j = LastCol
            For Attempt = 1 To 9
                .Cells(1, j + 1).Value = "ATT" & Attempt
                .Cells(1, j + 2).Value = "Date" & Attempt
                .Cells(1, j + 3).Value = "Notes" & Attempt
                j = j + 3
            Next Attempt
            Attempt = Attempt - 1
            
            
            ' Sample starts on row #2.
            ' Copy the rows to the separate worksheets.
            LastCol = GetLastCol(xlWsSrc)   'new last col
            For i = 2 To LastRow
                CoName = GetValidWsName(.Cells(i, 6).Value)
                If Not XL_WsExists(CoName) Then      'if new company
                    .Parent.Worksheets.Add(After:=(.Parent.Worksheets(.Parent.Worksheets.Count))).Name = CoName
                    Set xlWsNew = .Parent.Worksheets(.Parent.Worksheets.Count)
                    .Rows(1).Copy Destination:=xlWsNew.Rows(1)   'copy header to new sheet
                End If
                If xlWsNew Is Nothing Then Set xlWsNew = .Parent.Worksheets(CoName)
                CoRowNum = GetLastRow(xlWsNew) + 1
                .Range(.Cells(i, 1), .Cells(i, LastCol)).Copy Destination:=xlWsNew.Cells(CoRowNum, 1)
                
                For j = 1 To LastCol
                    .Cells(i, j).Formula = "='" & CoName & "'!" & xlWsNew.Cells(CoRowNum, j).Address
                Next j
                
            Next i
            
            .Activate
            .Cells(1, 1).Select
            
        End With
    
    Macro1_Proc_Exit:
        On Error GoTo 0
        Set xlWsSrc = Nothing
        Set xlWsNew = Nothing
        Application.CutCopyMode = False
        Application.ScreenUpdating = True
        Exit Sub
    Macro1_ErrorHandler:
        MsgBox "Error: " & Err.Number & " (" & Err.Description & ") in Sub 'Macro1' of Module 'Module1'.", vbOKOnly + vbCritical, "Error"
        Resume Macro1_Proc_Exit
      
    End Sub
    
    Function GetLastRow(Optional ByVal xlws As Excel.Worksheet, Optional ByVal iCol As Integer) As Integer
        On Error GoTo ErrorHandler
        Dim xlRng As Range
        If xlws Is Nothing Then Set xlws = ActiveSheet
        If iCol = 0 Then Set xlRng = xlws.Cells Else Set xlRng = xlws.Columns(iCol)
        With xlRng
            GetLastRow = .Find(What:="*", After:=.Cells(.Rows.Count, .Columns.Count), LookAt:=xlPart, SearchOrder:=xlByRows, SearchDirection:=xlPrevious, MatchCase:=False).Row
        End With
        Exit Function
    ErrorHandler:
        GetLastRow = 0
    End Function
    
    Function GetLastCol(Optional ByVal xlws As Excel.Worksheet, Optional ByVal iRow As Long) As Long
        On Error GoTo ErrorHandler
        Dim xlRng As Range
        If xlws Is Nothing Then Set xlws = ActiveSheet
        If iRow = 0 Then Set xlRng = xlws.Cells Else Set xlRng = xlws.Rows(iRow)
        With xlRng
            GetLastCol = .Find(What:="*", After:=.Cells(.Rows.Count, .Columns.Count), LookAt:=xlPart, SearchOrder:=xlByColumns, SearchDirection:=xlPrevious, MatchCase:=False).Column
        End With
        Exit Function
    ErrorHandler:
        GetLastCol = 0
    End Function
    
    Function GetValidWsName(ByVal wsName As String) As String
        Const INVALID_CHARS As String = ":\/?*[]"
        Dim i As Byte
        GetValidWsName = wsName
        For i = 1 To Len(INVALID_CHARS)
            GetValidWsName = Replace$(GetValidWsName, Mid(INVALID_CHARS, i, 1), vbNullString)
        Next
        GetValidWsName = Left$(GetValidWsName, 31)
    End Function
    
    Function XL_WsExists(ByVal wsName As String, Optional xlWb As Excel.Workbook) As Boolean
        On Error Resume Next
        Dim xlws As Worksheet
        If xlWb Is Nothing Then Set xlWb = ActiveWorkbook
        Set xlws = xlWb.Worksheets(wsName)
        XL_WsExists = (Err.Number = 0)
        Set xlws = Nothing
    End Function
    Please use [CODE]-TAGS
    When your problem is solved mark the thread SOLVED
    If an answer has helped you please click to give reputation
    Read the FORUM RULES

  2. #2
    Registered User
    Join Date
    06-25-2013
    Location
    Minnesota
    MS-Off Ver
    Excel 2010
    Posts
    10

    Re: ActiveSheet.Paste Link:= True Does Not Work After Awhile - 1004 MS Excel cannot paste



    Thank you so much for that code. I walked through the steps until it got through the main portion of populating the sheets. And it gets hung up in there somewhere. I will experiment some more in trying to figure out where it just sort of does not continue. I am re-attaching the Excel document again.

    Again, thank you very much for the help. I look forward to the final solution.
    Attached Files Attached Files

  3. #3
    Registered User
    Join Date
    06-25-2013
    Location
    Minnesota
    MS-Off Ver
    Excel 2010
    Posts
    10

    Re: ActiveSheet.Paste Link:= True Does Not Work After Awhile - 1004 MS Excel cannot paste

    Actually, the code works perfectly. Thank you so much. Z

+ Reply to Thread

Thread Information

Users Browsing this Thread

There are currently 1 users browsing this thread. (0 members and 1 guests)

Tags for this Thread

Bookmarks

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts

Search Engine Friendly URLs by vBSEO 3.6.0 RC 1