XL: Data Fields Not Included in PivotFields Collection

Last reviewed: February 2, 1998
Article ID: Q119318
The information in this article applies to:
  • Microsoft Excel for Windows, versions 5.0, 5.0c
  • Microsoft Excel for Windows 95, versions 7.0, 7.0a
  • Microsoft Excel 97 for Windows
  • Microsoft Excel for the Macintosh, versions 5.0, 5.0a
  • Microsoft Excel 98 Macintosh Edition

SYMPTOMS

When you are using the Microsoft Visual Basic Programming System, Applications Edition, included with Microsoft Excel, and you use the PivotFields collection to return the fields in a PivotTable, the fields in the data area (DataFields object) are not returned.

CAUSE

This behavior occurs because the PivotFields collection does not contain the DataFields object or the fields that are in the data area. Data fields are created from pivot fields, for example the data field "Sum of Profit" is created by dragging the pivot field "Profit" to the data area on the PivotTable in the PivotTable Wizard. Multiple data fields may be created from the same pivot field.

WORKAROUND

To return only the data fields in a PivotTable, use the DataFields object as in the following example:

Microsoft provides programming examples for illustration only, without warranty either expressed or implied, including, but not limited to, the implied warranties of merchantability and/or fitness for a particular purpose. This article assumes that you are familiar with the programming language being demonstrated and the tools used to create and debug procedures. Microsoft support engineers can help explain the functionality of a particular procedure, but they will not modify these examples to provide added functionality or construct procedures to meet your specific needs. If you have limited programming experience, you may want to contact the Microsoft fee-based consulting line at (800) 936-5200. For more information about the support options available from Microsoft, please see the following page on the World Wide Web:

   http://www.microsoft.com/supportnet/refguide/ 


   Sub DisplayDataFields()
       Dim x As Variant
       Dim Pivot1 As PivotTable
       Set Pivot1 = Worksheets(1).PivotTables("Pivot1")
       For Each x In Pivot1.DataFields
           'Display pivot field name (name of field in table)
           MsgBox "Pivotfield Name is " & x.Name
           'Display pivot field source name (name of field in original
           'data)
           MsgBox "Pivotfield SourceName is " & x.SourceName
       Next
   End Sub

To return the pivot fields that are visible in the PivotTable itself, use the VisibleFields property in place of the DataFields property as in the following line:

   For Each x In Pivot1.VisibleFields

STATUS

Microsoft has confirmed this to be a problem in the Microsoft products listed at the beginning of this article. We are researching this problem and will post new information here in the Microsoft Knowledge Base as it becomes available.

MORE INFORMATION

You can use the SourceName property of the PivotField object to return the name of the pivot field as it appears in the original source data for the pivot table. The Name property of the PivotField object returns the name of the pivot field as it appears in the table.

REFERENCES

For more information about the PivotField Object, choose the Search button in the Visual Basic Reference and type:

   pivot fields: described

For more information about the SourceName Property, choose the Search button in the Visual Basic Reference and type:

   SourceName Property

In Microsoft Excel 7.0, click Answer Wizard on the File menu, type the following:

   SourceName Property

and click Search.


Additional query words: 1.00 5.00 5.00a 5.00c 7.00 7.00a 97 98 XL98 XL97
XL7 XL5
Version : WINDOWS:5.0,5.0c,7.0,97; MACINTOSH:5.0,98
Platform : MACINTOSH WINDOWS


THE INFORMATION PROVIDED IN THE MICROSOFT KNOWLEDGE BASE IS PROVIDED "AS IS" WITHOUT WARRANTY OF ANY KIND. MICROSOFT DISCLAIMS ALL WARRANTIES, EITHER EXPRESS OR IMPLIED, INCLUDING THE WARRANTIES OF MERCHANTABILITY AND FITNESS FOR A PARTICULAR PURPOSE. IN NO EVENT SHALL MICROSOFT CORPORATION OR ITS SUPPLIERS BE LIABLE FOR ANY DAMAGES WHATSOEVER INCLUDING DIRECT, INDIRECT, INCIDENTAL, CONSEQUENTIAL, LOSS OF BUSINESS PROFITS OR SPECIAL DAMAGES, EVEN IF MICROSOFT CORPORATION OR ITS SUPPLIERS HAVE BEEN ADVISED OF THE POSSIBILITY OF SUCH DAMAGES. SOME STATES DO NOT ALLOW THE EXCLUSION OR LIMITATION OF LIABILITY FOR CONSEQUENTIAL OR INCIDENTAL DAMAGES SO THE FOREGOING LIMITATION MAY NOT APPLY.

Last reviewed: February 2, 1998
© 1998 Microsoft Corporation. All rights reserved. Terms of Use.