fbpx
Search
Close this search box.

A trick to Pivot text values

Share

Facebook
Twitter
LinkedIn

We all know that Pivot Tables are best thing since avocado on toast. But they can’t slice text values and spread them in a table with Pivots. So how to take a large blob of text and turn it in to something meaningful like below?

Simple, we use Power Query.

How to pivot text values – Tutorial

  • Let’s say your large chunk of meaty data is in a table named text
  • Select any cell in your table and go to Data > From Table (or Power Query > From Table)
  • Once your data is in PQ, split it by : (right click on the column and choose split column by > Delimiter)
  • Now, your data will become 2 columns. First column with FUNxxx reference and next column with rest of the text.
  • Go to second column and remove nulls (Filter > uncheck nulls)
  • Now replace all punctuation in second column using replace values
    • Replace ( ) , with spaces
  • Now split column 2 by delimiter = space. But this time, split in to rows (using advanced option as shown below)

  • Filter the rows on second column so you only have anything that begins with FUN or REQ
  • Select both columns and remove duplicates
  • Rename columns and load your data to Excel.
  • Done, your text is now pivoted.

Related: Introduction to Power Query

Pivoting Text Values – Video Tutorial

If the Power Query steps seem confusing, watch below quick video tutorial to understand how to pivot text values in Excel. You can also catch this on Chandoo.org YouTube Channel.

Download Text Value Pivot – Example workbook

Click here to download example workbook with the query steps. Go to Pivot tab and right click on the table to either refresh or edit.

Got few more minutes? Check out other awesome ways to use Power Query

If you have just 10 minutes to learn, I suggest spending that on below PQ tips. You will learn powerful new ways to deal with data pains.

Got a pesky text extraction / summary problem – post here

If you struggle processing text and want to learn new ways to deal with it, post your problem in comments. I will try to share solutions thru Excel / Power Query.

Alternatively, feel free to suggest your own methods to pivot text values in Excel.

 

Facebook
Twitter
LinkedIn

Share this tip with your colleagues

Excel and Power BI tips - Chandoo.org Newsletter

Get FREE Excel + Power BI Tips

Simple, fun and useful emails, once per week.

Learn & be awesome.

Welcome to Chandoo.org

Thank you so much for visiting. My aim is to make you awesome in Excel & Power BI. I do this by sharing videos, tips, examples and downloads on this website. There are more than 1,000 pages with all things Excel, Power BI, Dashboards & VBA here. Go ahead and spend few minutes to be AWESOME.

Read my storyFREE Excel tips book

Excel School made me great at work.
5/5

– Brenda

Excel formula list - 100+ examples and howto guide for you

From simple to complex, there is a formula for every occasion. Check out the list now.

Calendars, invoices, trackers and much more. All free, fun and fantastic.

Advanced Pivot Table tricks

Power Query, Data model, DAX, Filters, Slicers, Conditional formats and beautiful charts. It's all here.

Still on fence about Power BI? In this getting started guide, learn what is Power BI, how to get it and how to create your first report from scratch.

letter grades from test scores in Excel

How to convert test scores to letter grades in Excel?

We can use Excel’s LOOKUP function to quickly convert exam or test scores to letter grades like A+ or F. In this article, let me explain the process and necessary formulas. I will also share a technique to calculate letter grades from test scores using percentiles.

2 Responses to “A trick to Pivot text values”

  1. f(x)dx says:

    Cool trick

    Few comments from me:
    1. For older versions of Excel where 'Split into rows' is not available, the process would be the same. With one additional step after second colimn is split by spaces: Select first column and chose Transform > Unpivot other columns.

    2. Replacing ( ) , with spaces adds spaces you don't need. It is better to replace them with nothing (just don't put anithing in 'Replace with' field

    3. It is always good idea as a last step before loading the data to TRIM and CLEAN your column in order to remove unnecessary spaces and non-printing characters

    below is the M code of my query made in Excel 2013

    let
    Source = Excel.CurrentWorkbook(){[Name="text"]}[Content],
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Text", type text}}),
    #"Split Column by Delimiter" = Table.SplitColumn(#"Changed Type","Text",Splitter.SplitTextByEachDelimiter({":"}, QuoteStyle.Csv, false),{"Text.1", "Text.2"}),
    #"Changed Type1" = Table.TransformColumnTypes(#"Split Column by Delimiter",{{"Text.1", type text}, {"Text.2", type text}}),
    #"Filtered Rows" = Table.SelectRows(#"Changed Type1", each ([Text.2] null)),
    #"Replaced Value" = Table.ReplaceValue(#"Filtered Rows","(","",Replacer.ReplaceText,{"Text.2"}),
    #"Replaced Value1" = Table.ReplaceValue(#"Replaced Value",")","",Replacer.ReplaceText,{"Text.2"}),
    #"Split Column by Delimiter1" = Table.SplitColumn(#"Replaced Value1","Text.2",Splitter.SplitTextByDelimiter(" ", QuoteStyle.Csv),{"Text.2.1", "Text.2.2", "Text.2.3", "Text.2.4", "Text.2.5", "Text.2.6", "Text.2.7", "Text.2.8", "Text.2.9", "Text.2.10", "Text.2.11", "Text.2.12", "Text.2.13", "Text.2.14"}),
    #"Changed Type2" = Table.TransformColumnTypes(#"Split Column by Delimiter1",{{"Text.2.1", type text}, {"Text.2.2", type text}, {"Text.2.3", type text}, {"Text.2.4", type text}, {"Text.2.5", type text}, {"Text.2.6", type text}, {"Text.2.7", type text}, {"Text.2.8", type text}, {"Text.2.9", type text}, {"Text.2.10", type text}, {"Text.2.11", type text}, {"Text.2.12", type text}, {"Text.2.13", type text}, {"Text.2.14", type text}}),
    #"Unpivoted Other Columns" = Table.UnpivotOtherColumns(#"Changed Type2", {"Text.1"}, "Attribute", "Value"),
    #"Filtered Rows1" = Table.SelectRows(#"Unpivoted Other Columns", each Text.Contains([Value], "REQ") or Text.Contains([Value], "FUN")),
    #"Removed Columns" = Table.RemoveColumns(#"Filtered Rows1",{"Attribute"}),
    #"Replaced Value2" = Table.ReplaceValue(#"Removed Columns",",","",Replacer.ReplaceText,{"Value"}),
    #"Trimmed Text" = Table.TransformColumns(#"Replaced Value2",{{"Value", Text.Trim}}),
    #"Cleaned Text" = Table.TransformColumns(#"Trimmed Text",{{"Value", Text.Clean}}),
    #"Removed Duplicates" = Table.Distinct(#"Cleaned Text")
    in
    #"Removed Duplicates"

  2. Chihiro says:

    If you have PowerPivot as well as PowerQuery. You can use FIRSTNONBLANK() or LASTNONBLANK() to return text value into PivotTable via DAX Measure. I recently discovered this by accident while helping in thread below.
    https://chandoo.org/forum/threads/3-followup-dynamic-slicer-on-dimension-table-for-report-agains-data-in-fact-table.38392/

    And found following link that details it's use.
    https://www.sqlbi.com/articles/alternative-use-of-firstnonblank-and-lastnonblank/

Leave a Reply