+ Reply to Thread
Results 1 to 7 of 7

RDBmerge script and shared workbook

Hybrid View

  1. #1
    Registered User
    Join Date
    11-24-2014
    Location
    London
    MS-Off Ver
    Excel Mac 2011, V14.4.1 (140326) Upd: 14.4.1
    Posts
    20

    Question RDBmerge script and shared workbook

    Hi All,

    Please see the below script I'm using, it works as a single user workbook however it fails when it's converted to a shared workbook.

    The macro when run, copies all of the required data from the array of sheets and collates them into a new sheet called RDBmerge, when I re-run the macro it will re-collate the data to ensure the latest information is in the RDBmerge sheet.

    When I covert this to a shared workbook it gives me a runtime error and produces an empty sheet called 'Sheet1'.

    The error states:

    Run-time error '1004':

    That sheet name is already in use. Enter a sheet name that is not in use by another sheet.

    Does anyone know why this is happening and what I need to do to stop it?

    Module:

    Sub CopyDataWithoutHeaders()
        Dim sh As Worksheet
        Dim DestSh As Worksheet
        Dim Last As Long
        Dim shLast As Long
        Dim CopyRng As Range
        Dim StartRow As Long
    
        With Application
            .ScreenUpdating = False
            .EnableEvents = False
        End With
    
        'Delete the sheet "RDBMergeSheet" if it exist
        Application.DisplayAlerts = False
        On Error Resume Next
        ActiveWorkbook.Worksheets("RDBMergeSheet").Delete
        On Error GoTo 0
        Application.DisplayAlerts = True
    
        'Add a worksheet with the name "RDBMergeSheet"
        Set DestSh = ActiveWorkbook.Worksheets.Add
        DestSh.Name = "RDBMergeSheet"
    
        'Fill in the start row
        StartRow = 7
    
        'loop through all worksheets and copy the data to the DestSh
        For Each sh In ActiveWorkbook.Sheets(Array("Employee 1", "Employee 2", "Employee 3", "Employee 4"))
    
                'Find the last row with data on the DestSh and sh
                Last = LastRow(DestSh)
                shLast = LastRow(sh)
    
                'If sh is not empty and if the last row >= StartRow copy the CopyRng
                If shLast > 0 And shLast >= StartRow Then
    
                    'Set the range that you want to copy
                    Set CopyRng = sh.Range(sh.Rows(StartRow), sh.Rows(shLast))
    
                    'Test if there enough rows in the DestSh to copy all the data
                    If Last + CopyRng.Rows.Count > DestSh.Rows.Count Then
                        MsgBox "There are not enough rows in the Destsh"
                        GoTo ExitTheSub
                    End If
    
                    'This example copies values/formats, if you only want to copy the
                    'values or want to copy everything look below example 1 on this page
                    CopyRng.Copy
                    With DestSh.Cells(Last + 1, "A")
                        .PasteSpecial xlPasteValues
                        .PasteSpecial xlPasteFormats
                        Application.CutCopyMode = False
                    End With
    
                End If
    
        Next
    
    ExitTheSub:
    
        Application.Goto DestSh.Cells(1)
    
        'AutoFit the column width in the DestSh sheet
        DestSh.Columns.AutoFit
    
        With Application
            .ScreenUpdating = True
            .EnableEvents = True
        End With
    End Sub
    Functions Module:

    Function LastRow(sh As Worksheet)
        On Error Resume Next
        LastRow = sh.Cells.Find(What:="*", _
                                After:=sh.Range("A1"), _
                                Lookat:=xlPart, _
                                LookIn:=xlFormulas, _
                                SearchOrder:=xlByRows, _
                                SearchDirection:=xlPrevious, _
                                MatchCase:=False).Row
        On Error GoTo 0
    End Function
    
    
    Function LastCol(sh As Worksheet)
        On Error Resume Next
        LastCol = sh.Cells.Find(What:="*", _
                                After:=sh.Range("A1"), _
                                Lookat:=xlPart, _
                                LookIn:=xlFormulas, _
                                SearchOrder:=xlByColumns, _
                                SearchDirection:=xlPrevious, _
                                MatchCase:=False).Column
        On Error GoTo 0
    End Function
    Thanks

    Matt

  2. #2
    Forum Contributor
    Join Date
    09-05-2011
    Location
    Essex, England
    MS-Off Ver
    Excel 2003 Excel 2007
    Posts
    383

    Re: RDBmerge script and shared workbook

    VBA in shared workbooks as far as I can tell isn't very well supported, its not to say VBA won't run in a shared workbook but its very prone to failure as the entire dynamic of the workbook has changed including various properties.

    if you HAVE to use a shared workbook avoid vba.

  3. #3
    Forum Expert nigelog's Avatar
    Join Date
    12-14-2007
    Location
    Cork, Ireland
    MS-Off Ver
    Office 365 Windows 10
    Posts
    2,293

    Re: RDBmerge script and shared workbook

    Use
    ActiveWorkbook.ExclusiveAccess
    to temporarily "unshare" workbook - run your macro then save file as shared again
    ActiveWorkbook.SaveAs ActiveWorkbook.Name, accessmode:=xlShared

  4. #4
    Forum Expert nigelog's Avatar
    Join Date
    12-14-2007
    Location
    Cork, Ireland
    MS-Off Ver
    Office 365 Windows 10
    Posts
    2,293

    Re: RDBmerge script and shared workbook

    Sub CopyDataWithoutHeaders()
        Dim sh As Worksheet
        Dim DestSh As Worksheet
        Dim Last As Long
        Dim shLast As Long
        Dim CopyRng As Range
        Dim StartRow As Long
    
        With Application
            .ScreenUpdating = False
            .EnableEvents = False
    
        End With
    ActiveWorkbook.ExclusiveAccess
    
        'Delete the sheet "RDBMergeSheet" if it exist
        Application.DisplayAlerts = False
        On Error Resume Next
        ActiveWorkbook.Worksheets("RDBMergeSheet").Delete
        On Error GoTo 0
        Application.DisplayAlerts = True
    
        'Add a worksheet with the name "RDBMergeSheet"
        Set DestSh = ActiveWorkbook.Worksheets.Add
        DestSh.Name = "RDBMergeSheet"
    
        'Fill in the start row
        StartRow = 7
    
        'loop through all worksheets and copy the data to the DestSh
        For Each sh In ActiveWorkbook.Sheets(Array("Employee 1", "Employee 2", "Employee 3", "Employee 4"))
    
                'Find the last row with data on the DestSh and sh
                Last = LastRow(DestSh)
                shLast = LastRow(sh)
    
                'If sh is not empty and if the last row >= StartRow copy the CopyRng
                If shLast > 0 And shLast >= StartRow Then
    
                    'Set the range that you want to copy
                    Set CopyRng = sh.Range(sh.Rows(StartRow), sh.Rows(shLast))
    
                    'Test if there enough rows in the DestSh to copy all the data
                    If Last + CopyRng.Rows.Count > DestSh.Rows.Count Then
                        MsgBox "There are not enough rows in the Destsh"
                        GoTo ExitTheSub
                    End If
    
                    'This example copies values/formats, if you only want to copy the
                    'values or want to copy everything look below example 1 on this page
                    CopyRng.Copy
                    With DestSh.Cells(Last + 1, "A")
                        .PasteSpecial xlPasteValues
                        .PasteSpecial xlPasteFormats
                        Application.CutCopyMode = False
                    End With
    
                End If
    
        Next
    
    ExitTheSub:
    
        Application.Goto DestSh.Cells(1)
    
        'AutoFit the column width in the DestSh sheet
        DestSh.Columns.AutoFit
    ActiveWorkbook.SaveAs ActiveWorkbook.Name, accessmode:=xlShared
        With Application
            .ScreenUpdating = True
            .EnableEvents = True
        End With
    End Sub

  5. #5
    Registered User
    Join Date
    11-24-2014
    Location
    London
    MS-Off Ver
    Excel Mac 2011, V14.4.1 (140326) Upd: 14.4.1
    Posts
    20

    Re: RDBmerge script and shared workbook

    Thank you Nigelog. This has worked perfectly!

  6. #6
    Forum Guru xlnitwit's Avatar
    Join Date
    06-27-2016
    Location
    London
    MS-Off Ver
    Windows: 2010; Mac: 16.13 (O365)
    Posts
    7,085

    Re: RDBmerge script and shared workbook

    Hi,

    You can't delete worksheets in a shared workbook, so the code to delete the existing RDBMerge sheet will fail, and then when you try to add a new sheet and give it the same name, it errors. Replace this section
        'Delete the sheet "RDBMergeSheet" if it exist
        Application.DisplayAlerts = False
        On Error Resume Next
        ActiveWorkbook.Worksheets("RDBMergeSheet").Delete
        On Error GoTo 0
        Application.DisplayAlerts = True
    
        'Add a worksheet with the name "RDBMergeSheet"
        Set DestSh = ActiveWorkbook.Worksheets.Add
        DestSh.Name = "RDBMergeSheet"
    with this
        'Delete the sheet "RDBMergeSheet" if it exist
    
        On Error Resume Next
        Set DestSh = ActiveWorkbook.Worksheets("RDBMergeSheet")
        DestSh.UsedRange.Clear
        On Error GoTo 0
     
        'Add a worksheet with the name "RDBMergeSheet"
        If DestSh Is Nothing then
            Set DestSh = ActiveWorkbook.Worksheets.Add
            DestSh.Name = "RDBMergeSheet"
        End If
    Don
    Please remember to mark your thread 'Solved' when appropriate.

  7. #7
    Forum Expert nigelog's Avatar
    Join Date
    12-14-2007
    Location
    Cork, Ireland
    MS-Off Ver
    Office 365 Windows 10
    Posts
    2,293

    Re: RDBmerge script and shared workbook

    No problem
    can you mark thread as solved.

+ Reply to Thread

Thread Information

Users Browsing this Thread

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

Similar Threads

  1. Running Macro on shared protected/shared workbook?
    By taylorsm in forum Excel Programming / VBA / Macros
    Replies: 0
    Last Post: 01-27-2017, 10:56 AM
  2. Replies: 3
    Last Post: 04-05-2016, 11:41 AM
  3. Email rule in outlook with VBA script on shared mailbox
    By CR7 in forum Excel Programming / VBA / Macros
    Replies: 0
    Last Post: 07-08-2015, 09:01 AM
  4. Excel Macro using VB Script to send emails from Common/Shared Mailbox
    By k.vijayendran in forum Excel Programming / VBA / Macros
    Replies: 0
    Last Post: 09-11-2014, 01:48 PM
  5. Replies: 0
    Last Post: 04-10-2014, 03:31 AM
  6. RDBMerge Add-in not seeing files
    By mstrauss in forum Excel Programming / VBA / Macros
    Replies: 0
    Last Post: 09-09-2013, 04:36 PM
  7. Excel VB script which locks cell after single use in shared work book
    By yashwanth2014 in forum Excel Programming / VBA / Macros
    Replies: 3
    Last Post: 11-16-2008, 02:20 PM

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