XL: How to Simulate a PivotTable with No SummarizationLast reviewed: February 3, 1998Article ID: Q149576 |
The information in this article applies to:
SUMMARYIn Microsoft Excel, when you use the PivotTable command to create a table from a list, the data is always summarized according to the option that is selected in the Summarize By list of the PivotTable Field dialog box. Because this list box does not have a "no summarization" option, there is no way to use a PivotTable to tabulate the data without summarizing it in some way. This article shows how you can use Microsoft Visual Basic for Applications code to create such a table.
MORE INFORMATIONMicrosoft 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/support/supportnet/refguide/default.aspAs an example, suppose a company makes four products, each of which comes in three sizes. To use the sample code provided below, create a Microsoft Excel worksheet containing the following information:
A1:Cust. B1: Product C1:Size D1: E1: F1:Sml G1:Med H1:Lrg A2: J B2: widget C2: sml D2: E2: Doodad F2: G2: H2: A3: B B3: gizmo C3: med D3: E3: Gizmo F3: G3: H3: A4: C B4: doodad C4: sml D4: E4: Thing F4: G4: H4: A5: F B5: gizmo C5: lrg D5: E5: Widget F5: G5: H5: A6: M B6: doodad C6: lrg D6: E6: F6: G6: H6: A7: A B7: gizmo C7: sml D7: E7: F7: G7: H7: A8: A B8: doodad C8: lrg D8: E8: F8: G8: H8: A9: H B9: gizmo C9: sml D9: E9: F9: G9: H9: A10:J B10:widget C10:med D10:E10: F10: G10: H10:Suppose you want to create a table that lists the customers for each product in each size. Because a PivotTable always summarizes in some manner (that is, by using the Sum, Count, Average, or other function), there is no way you can use the PivotTable command to accomplish the task, short of setting up separate columns for each customer. The following code uses the column headings in row 1 and the row headings in column E to accomplish the task.
Sub BuildTable() Dim ListRow, TableRow, TableColumn As Integer Dim TableEntry As String Dim CellToFill As Range Range("F2:H5").ClearContents ListRow = 2 Do Until Cells(ListRow, 1).Value = "" ' Get table entry from first column of list. TableEntry = Cells(ListRow, 1).Value ' Get position of product name within range of row titles. TableRow = Application.Match(Cells(ListRow, 2), _ Range("E2:E5"), 0) ' Get position of product size within range of column titles. TableColumn = Application.Match(Cells(ListRow, 3), _ Range("f1:h1"), 0) Set CellToFill = Range("e1").Offset(TableRow, TableColumn) ' If there's already an entry in the cell, ' separate it from the new entry with a comma and space. If CellToFill.Value <> "" Then CellToFill.Value = _ CellToFill.Value & "," ' Add the new entry to the cell. CellToFill.Value = CellToFill.Value & TableEntry ListRow = ListRow + 1 Loop End SubThe results on the worksheet will appear as follows:
E1: F1:Sml G1:Med H1:Lrg E2: Doodad F2:C G2: H2:M,A E3: Gizmo F3:A,H G3:B H3:F E4: Thing F4: G4: H4: E5: Widget F5:J G5:J H5:NOTE: You are still subject to the 255 characters per cell limitation. Also, the macro does not format the columns to display all of the information in each cell. You may want to use Format, Column, or Wrap Text to do this.
|
Additional query words: 5.00 5.00c 7.00 8.00 XL98 XL97 XL7 XL5
© 1998 Microsoft Corporation. All rights reserved. Terms of Use. |