ID: Q127208
The information in this article applies to:
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 desired on the worksheet, and then create a custom list using the sorted source data.
The following examples demonstrate how to use a custom list to prevent a PivotTable from sorting and to custom sort the data in your PivotTable.
Similar to when data is sorted on a worksheet, a PivotTable will first use 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, which will 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 recreate the pivot table (you can't just refresh the PivotTable).
1. 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
2. On the Data menu, click PivotTable. In the PivotTable Wizard - Step
1 of 4 dialog box, click Next. In the PivotTable Wizard - Step 2 of 4
dialog box, in the Range box, type "$A$1:$B$10" (without the quotation
marks), and click Next.
3. In the PivotTable Wizard - Step 3 of 4 dialog box, drag the MyNoSort
field to the Column area on the PivotTable. Drag the MyValues field to
the Data area on the PivotTable. Click Next.
4. In the PivotTable Wizard - Step 4 of 4 dialog box, in the PivotTable
starting cell box, enter "=$E$1" (without the quotation marks), and
click Finish.
Note the order of the values in the PivotTable.
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.
1. On the Tools menu, click Options, and click the Custom Lists tab.
2. Click in the Import List From Cells box.
3. On the worksheet, select the range of cells that contain your custom
list, (A2:A10 in this example) and click Import. Click OK.
4. Repeat these steps for each custom list. Then, create your PivotTable.
To use this custom list to sort your PivotTable, you must delete the PivotTable created above, and then create the PivotTable again, using the steps in the "Creating the PivotTable" procedure.
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.
The following example shows how to make a PivotTable field appear not to sort using a Visual Basic macro:
1. In a new module sheet, enter the following:
Sub NewPivotNoSort()
' Create temporary custom list using PivotTable data
Application.AddCustomList Range("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
2. 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
3. To run the macro, do the following:
a. Select any cell in the range A1:B10 on the worksheet that contains
the data that you entered above.
b. On the Tools menu, click Macro.
c. In the Macro Name/Reference list, click NewPivotNoSort and click
Run.
In the resulting PivotTable, the MyNoSortField data appears unsorted.
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 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/
Additional query words: 7.00 disable stop sorting 5.00 5.00c
Keywords : kbcode kbprg kbualink97
Version : WINDOWS:5.0,5.0c,7.0; MACINTOSH:5.0,5.0a
Platform : MACINTOSH WINDOWS
Issue type : kbinfo
Last Reviewed: May 17, 1999