SUMMARY
This step-by-step article describes how to custom sort a PivotTable or keep a PivotTable from being automatically sorted.
In Microsoft Excel, data in a PivotTable is automatically sorted.
There are no options available to turn this automatic sorting off or
to perform a custom sort on your PivotTable data.
To prevent a PivotTable from being sorted, you can create a custom list
using the unsorted source data on the worksheet. To custom sort a
PivotTable, you can first sort the source data as the way you want it on the
worksheet, and then create a custom list using the sorted source data.
A PivotTable first uses a custom list to sort if possible. If an appropriate custom list is not available, then the PivotTable uses default sorting.
If there is a custom list that exactly matches the source data, then
the PivotTable is sorted using the custom list. This may make the
PivotTable appear to be unsorted.
Note that a custom list is only used when the PivotTable is created.
If you use a new custom list for sorting, you must re-create the pivot
table (you cannot just refresh the PivotTable).
The following examples demonstrate how to use a custom list to
prevent a PivotTable from sorting and how to custom sort the data in
your PivotTable.
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 professionals 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 a Microsoft Certified Partner or the Microsoft fee-based
consulting line at (800) 936-5200. For more information about Microsoft Certified
Partners, please visit the following Microsoft Web site:
For more information about the support options that are available and about how to contact Microsoft, visit the following Microsoft Web site:
back to the top
Create the PivotTable
- To create a PivotTable in this example, enter the following on a worksheet in a new workbook:
A1: MyNoSortField B1: MyValues
A2: NoSort4 B2: 5
A3: NoSort2 B3: 3
A4: NoSort1 B4: 5
A5: NoSort3 B5: 6
A6: NoSort4 B6: 4
A7: NoSort3 B7: 3
A8: NoSort2 B8: 5
A9: NoSort3 B9: 7
A10: NoSort1 B10: 4
- On the Data menu, click PivotTable and PivotChart Report. In the PivotTable and PivotChart Wizard, step
1, click Next. In Step 2 of the wizard, type A1:B10, and then click Next.
- In step 3 of the wizard, click Layout. Drag the MyNoSort
field to the Column area, drag the MyValues field to
the Data area, and then click OK.
- In the PivotTable and PivotChart Wizard-Step 3 of 3 dialog box, click Existing worksheet, type E1, and then click Finish.
Note the order of the values in the PivotTable.
back to the top
Create the Custom List
To create a custom list to affect the way your PivotTable data is
sorted, first make sure that the cells from which you are creating
the list contain text, not formulas or numeric values. If the cells
contain formulas, you must first copy the formulas, and then paste
the values to another location to create text; if the cells contain
numeric values, you will not be able to create a custom list, even if
you format the values as text.
- On the Tools menu, click Options, and then click the Custom Lists tab.
- In the Import list from cells box, type A2:A10 (the range of cells that contain your custom
list), click Import, and then click OK.
- Repeat these steps for each custom list. Then, create your PivotTable.
back to the top
Use the Custom List
To use this custom list to sort your PivotTable, you must delete the
PivotTable created earlier, and then create the PivotTable again. To create the PivotTable, follow the steps in the
Create the PivotTable section of this article.
NOTES: If you add items to the source data after you create the PivotTable, and you refresh the PivotTable, the new items are only sorted
correctly if they are included in the original custom list. Items
that are not included in the original custom list are sorted after
the items that are included in the original custom list.
After you create a PivotTable using a custom list, the PivotTable
no longer uses the custom list for refreshing the data. Because of
this behavior, if you change the custom list that you used to create
the PivotTable, you must delete the PivotTable, and create a new
PivotTable. Additionally, you can delete the original custom list
and the PivotTable will still sort according to the original custom
list.
back to the top
Visual Basic Code Example
The following example shows how to use a Visual Basic macro to make a PivotTable field appear not to sort:
- In a new module sheet, type the following code:
Sub NewPivotNoSort()
' Create temporary custom list using PivotTable data
Application.AddCustomList Array("A2:A10")
' Create PivotTable
ActiveSheet.PivotTableWizard
ActiveSheet.PivotTables(1).AddFields "MyNoSortField"
ActiveSheet.PivotTables(1).PivotFields("MyValues").Orientation _
= xlDataField
' Delete custom list
Application.DeleteCustomList Application.CustomListCount
End Sub
- On a worksheet in the same workbook, enter the following:
A1: MyNoSortField B1: MyValues
A2: NoSort4 B2: 5
A3: NoSort2 B3: 3
A4: NoSort1 B4: 5
A5: NoSort3 B5: 6
A6: NoSort4 B6: 4
A7: NoSort3 B7: 3
A8: NoSort2 B8: 5
A9: NoSort3 B9: 7
A10: NoSort1 B10: 4
- To run the macro, follow these steps:
- Select any cell in the range A1:B10 on the worksheet that contains
the data that you entered above.
- On the Tools menu, click Macro.
- In the Macro Name/Reference list, click NewPivotNoSort, and then click
Run.
In the resulting PivotTable, the MyNoSortField data appears unsorted.
back to the top