Pivot Table With Text in Values Area


July 10, 2018 - by Bill Jelen

Pivot Table With Text in Values Area
Eliminate Pivot Table Annoyances

Can you build a pivot table with text in the values area? Susan from Melbourne Florida has a text field and wants to see the before and after of that text.

Traditionally, you can not move a text field in to the values area of a pivot table.

Typically, you can not put those words in the values area of a pivot table.
Typically, you can not put those words in the values area of a pivot table.

However, if you use the Data Model, you can write a new calculated field in the DAX language that will show text as the result.


  1. Make sure your data is Formatted as Table by choosing one cell in the data and pressing Ctrl + T. Make a note of the table name as shown on the Table Tools tab of the ribbon.
  2. Insert, Pivot Table. Choose "Add This Data to the Data Model" while creating the pivot table.

    The Data Model unlocks many features
    The Data Model unlocks many features


  3. Drag fields to the Rows and Columns of the pivot table.

    Start building the pivot table
    Start building the pivot table
  4. To add the text to the values area, you have to create a new special kind of calculated field called a Measure. Look at the top of the Pivot Table Fields list for the table name. Right-click the table name and choose Add Measure.

    Note

    If you do not have this option, then you did not choose Add This Data To The Data Model in step 2.

    Measures allow more functions than traditional fields
    Measures allow more functions than traditional fields
  5. Type a field name of ListOfCodes
  6. The formula is =CONCATENATEX(Table1,Table1[Code],", ")
  7. Leave the format as General
  8. Click Check DAX Formula to make sure there are no typos

    Set up the Measure
    Set up the Measure
  9. Click OK. The new measure will appear in the field list.

    Drag this field to the Values area
    Drag this field to the Values area
  10. When you drag ListOfCodes to the Values area, you will see a list of codes for each cell in the values area.

    Chris in LAX changed from Apple to Fig
    Chris in LAX changed from Apple to Fig

Note

It is probably important to remove grand totals from this pivot table. Otherwise, the intersection of the Grand Total Row and Grand Total Column will list all of the codes in the table separated by columns. You can go to PivotTable Tools Design, Grand Totals, Off for Rows and Columns.

Amazingly, as you re-arrange the fields in Rows & Columns, the CONCATENATEX updates.

After changing the fields in the rows & columns
After changing the fields in the rows & columns

After using this method for a few weeks, I and others noticed that in some data sets, the concatenated values would contain duplicates, such as the Fig, Fig data shown in the East region above. Thanks to Rob Collie at PowerPivotPro.com, you can remove the duplicates by changing

=CONCATENATEX(Table1, Table1[Code], ”, “)

to

=CONCATENATEX(Values(Table1[Code]), Table1[Code], ", ")

The VALUES function returns a new table with the unique values found in a column.

Watch Video

Download Excel File

To download the excel file: pivot-table-with-text-in-values-area.xlsx

The DAX formula language allows many new calculations in a pivot table.

Excel Thought Of the Day

I've asked my Excel Master friends for their advice about Excel. Today's thought to ponder:

"Excel conquers all"

Title Photo: Amador Loureiro on Unsplash