Excel VBA macro that creates a pivot table works for one user but not another

Eagle72

New Member
Joined
Apr 5, 2005
Messages
21
Hi,
I have a strange one. I wrote a macro that creates a table from data exported out of our MRP system and then summarizes it in a pivot table.
Everything works for me but when I watched another user try to use it, it created the table and the second sheet but the second sheet is empty. No error messages popped up. He hasn't used macros before - is there some setting in his Excel that needs to be turned on? We both run 32 bit versions of Excel 365. The code is only run on a fresh copy of the file and only contains Sheet1 with the raw data.
Here is the code:

VBA Code:
Sub MB51_Create_Pivot_Table()
'
    Dim x As Integer
    On Error Resume Next
    Application.CutCopyMode = False
    Range("A1").Select
    ActiveSheet.ListObjects.Add(xlSrcRange, Range(ActiveCell, ActiveCell.End(xlDown).End(xlToRight)), , xlYes).Name _
        = "Table1"
    Range("Table1[#All]").Select
    Sheets.Add
    ActiveWorkbook.PivotCaches.Create(SourceType:=xlDatabase, SourceData:= _
        "Table1", Version:=7).CreatePivotTable TableDestination:="Sheet2!R3C1", _
        TableName:="PivotTable1", DefaultVersion:=7
    Sheets("Sheet2").Select
    Cells(3, 1).Select
    With ActiveSheet.PivotTables("PivotTable1")
        .ColumnGrand = True
        .HasAutoFormat = True
        .DisplayErrorString = False
        .DisplayNullString = True
        .EnableDrilldown = True
        .ErrorString = ""
        .MergeLabels = False
        .NullString = ""
        .PageFieldOrder = 2
        .PageFieldWrapCount = 0
        .PreserveFormatting = True
        .RowGrand = True
        .SaveData = True
        .PrintTitles = False
        .RepeatItemsOnEachPrintedPage = True
        .TotalsAnnotation = False
        .CompactRowIndent = 1
        .InGridDropZones = False
        .DisplayFieldCaptions = True
        .DisplayMemberPropertyTooltips = False
        .DisplayContextTooltips = True
        .ShowDrillIndicators = True
        .PrintDrillIndicators = False
        .AllowMultipleFilters = False
        .SortUsingCustomLists = True
        .FieldListSortAscending = False
        .ShowValuesRow = False
        .CalculatedMembersInFilters = False
        .RowAxisLayout xlCompactRow
    End With
    With ActiveSheet.PivotTables("PivotTable1").PivotCache
        .RefreshOnFileOpen = False
        .MissingItemsLimit = xlMissingItemsDefault
    End With
    ActiveSheet.PivotTables("PivotTable1").RepeatAllLabels xlRepeatLabels
    With ActiveSheet.PivotTables("PivotTable1").PivotFields("Movement Type")
        .Orientation = xlRowField
        .Position = 1
    End With
    With ActiveSheet.PivotTables("PivotTable1").PivotFields("Plant")
        .Orientation = xlColumnField
        .Position = 1
    End With
    ActiveSheet.PivotTables("PivotTable1").AddDataField ActiveSheet.PivotTables( _
        "PivotTable1").PivotFields("Quantity"), "Sum of Quantity", xlSum
    With ActiveSheet.PivotTables("PivotTable1").PivotFields("Movement Type")
        For x = 101 To 1000
            .PivotItems("" & x & "").Visible = False
        Next
        .PivotItems("261").Visible = True
        .PivotItems("601").Visible = True
        .PivotItems("Z21").Visible = False
    End With
End Sub

Thanks for your help,
Russ
 

Excel Facts

How to find 2nd largest value in a column?
MAX finds the largest value. =LARGE(A:A,2) will find the second largest. =SMALL(A:A,3) will find the third smallest
Remove the On Error Resume Next then try it on his machine. You really shouldn't just put that at the start of code and leave it in effect since it prevents you figuring out what went wrong and where.
 
Upvote 0
Thanks for the suggestion. It is required for those last With/ End With lines since some of the values won't exist in some of the data sets. But I should put it down there instead since clearly it isn't properly performing the earlier commands.
 
Upvote 0
So now I've able to determine that the line that causes the error is the last one shown below:
VBA Code:
Dim x As Integer
    Application.CutCopyMode = False
    Range("A1").Select
    ActiveSheet.ListObjects.Add(xlSrcRange, Range(ActiveCell, ActiveCell.End(xlDown).End(xlToRight)), , xlYes).Name _
        = "Table1"
    Range("Table1[#All]").Select
    Sheets.Add
    ActiveWorkbook.PivotCaches.Create(SourceType:=xlDatabase, SourceData:= _
        "Table1", Version:=7).CreatePivotTable TableDestination:="Sheet2!R3C1", _
        TableName:="PivotTable1", DefaultVersion:=7

This generates a Run-time error '5': invalid procedure call or argument.
The entire macro works fine on my machine but doesn't on this other user. Is there an improvement to the syntax that will prevent this error?
 
Upvote 0
I’d guess you have different versions of office, so remove the Version:=7 and DefaultVersion:=7 arguments.
 
Upvote 0
Solution

Forum statistics

Threads
1,224,823
Messages
6,181,181
Members
453,022
Latest member
Mohamed Magdi Tawfiq Emam

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