Why won't pivot work?

theta

Well-known Member
Joined
Jun 9, 2009
Messages
960
Hi All. I have a large range. When I select A1:CC130000 I can create a pivot manually no problems.

I can record a macro to produce the pivot. With a smaller range it works fine, but when using the above range it fails. PivotCache failed error

This is very frustrating, just used macro recorder to produce a dirty pivot in its basic form and it still fails

Ideas?
 
Thanks for your help Rorya, I can now use the (previous) elegant solution but with your reference fix.

How hard would it be to remove the 'XML Data' and replace with oWS.Name, but within the R1C1 method?

aut viam inveniam aut faciam

Code:
Private Function CreateXMLpivots(owb As Workbook, oWS As Worksheet) As Boolean
'Purpose: Create Pivots from source XML data
    Dim oPC As PivotCache
    Dim oPT As PivotTable
    
    Dim nLastRow As Long, nLastCol As Long
    
'    On Error Resume Next 'GoTo ErrHandler
        
    nLastRow = Last("Row", oWS.UsedRange)
    nLastCol = Last("Col", oWS.UsedRange)
    
    'oWS.Range(oWS.Cells(1, 1), oWS.Cells(nLastRow, nLastCol))
    Set oPC = owb.PivotCaches.Create(xlDatabase, "'XML Data'!R1C1:R" & nLastRow & "C" & nLastCol)
        
    owb.Worksheets.Add(after:=owb.Worksheets(owb.Worksheets.Count)).Name = "HPMN"
    owb.Sheets("HPMN").Tab.Color = 49407
    Set oPT = oPC.CreatePivotTable(owb.Sheets("HPMN").Range("A1"), "HPMN Codes", True)
         
    With oPT
        .DisplayFieldCaptions = True
        .ColumnGrand = True
        .SaveData = False
    End With
    
    'Add Data fields first, otherwise RowField is replaced
    oPT.AddDataField field:=oPT.PivotFields("TapSeqNo"), Function:=xlMin
    oPT.AddDataField field:=oPT.PivotFields("TapSeqNo"), Function:=xlMax
    oPT.AddDataField field:=oPT.PivotFields("TotalNetCharge"), Function:=xlSum
    oPT.AddDataField field:=oPT.PivotFields("TotalTax"), Function:=xlSum
    oPT.AddFields RowFields:=oPT.PivotFields("HPMN").Name
    oPT.TableRange1.Columns(2).NumberFormat = "#,###,##0"
    oPT.TableRange1.Columns(3).NumberFormat = "#,###,##0"
    oPT.TableRange1.Columns(4).NumberFormat = "#,###,##0.00"
    oPT.TableRange1.Columns(5).NumberFormat = "#,###,##0.00"
    owb.Sheets("HPMN").Range("A3").Select
    ActiveWindow.FreezePanes = True
    
    If owb.Sheets("HPMN").PivotTables.Count > 0 Then
       frmWait.lbxInfo.AddItem "HPMN Pivot created"
       CreateXMLpivots = True
    Else
       frmWait.lbxInfo.AddItem "*** HPMN Pivot NOT created ***"
       CreateXMLpivots = False
    End If
TheEnd:
    Set oPC = Nothing
    Set oPT = Nothing
    Exit Function
ErrHandler:
    Call LogErr("CreateXMLpivots", Err.Number, Err.Description)
    GoTo TheEnd
End Function
 
Upvote 0

Excel Facts

Format cells as currency
Select range and press Ctrl+Shift+4 to format cells as currency. (Shift 4 is the $ sign).
Simple:
Code:
Set oPC = owb.PivotCaches.Create(xlDatabase, "'" & oWS.Name & "'!R1C1:R" & nLastRow & "C" & nLastCol)
:)
 
Upvote 0
This is great, thanks! All working fine now.

Quirks...difference between a pro and an advanced user :)
 
Upvote 0

Forum statistics

Threads
1,224,586
Messages
6,179,729
Members
452,939
Latest member
WCrawford

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