• Skip to main content
  • Skip to header right navigation
  • Skip to site footer

My Online Training Hub

Learn Dashboards, Excel, Power BI, Power Query, Power Pivot

  • Courses
  • Pricing
    • Free Courses
    • Power BI Course
    • Excel Power Query Course
    • Power Pivot and DAX Course
    • Excel Dashboard Course
    • Excel PivotTable Course – Quick Start
    • Advanced Excel Formulas Course
    • Excel Expert Advanced Excel Training
    • Excel Tables Course
    • Excel, Word, Outlook
    • Financial Modelling Course
    • Excel PivotTable Course
    • Excel for Customer Service Professionals
    • Excel for Operations Management Course
    • Excel for Decision Making Under Uncertainty Course
    • Excel for Finance Course
    • Excel Analysis ToolPak Course
    • Multi-User Pricing
  • Resources
    • Free Downloads
    • Excel Functions Explained
    • Excel Formulas
    • Excel Add-ins
    • IF Function
      • Excel IF Statement Explained
      • Excel IF AND OR Functions
      • IF Formula Builder
    • Time & Dates in Excel
      • Excel Date & Time
      • Calculating Time in Excel
      • Excel Time Calculation Tricks
      • Excel Date and Time Formatting
    • Excel Keyboard Shortcuts
    • Excel Custom Number Format Guide
    • Pivot Tables Guide
    • VLOOKUP Guide
    • ALT Codes
    • Excel VBA & Macros
    • Excel User Forms
    • VBA String Functions
  • Members
    • Login
    • Password Reset
  • Blog
  • Excel Webinars
  • Excel Forum
    • Register as Forum Member

table transformation|Power Query|Excel Forum|My Online Training Hub

You are here: Home / table transformation|Power Query|Excel Forum|My Online Training Hub
Avatar
sp_LogInOut Log In sp_Registration Register
sp_Search Search
Advanced Search|Last Search Results
Search
Forum Scope




Match



Forum Options



Minimum search word length is 3 characters - maximum search word length is 84 characters
sp_Search Search
sp_RankInfo
Lost password?
sp_CrumbsHome HomeExcel ForumPower Querytable transformation
sp_PrintTopic sp_TopicIcon
table transformation
Avatar
pav hun
Member
Members
Level 0
Forum Posts: 8
Member Since:
August 17, 2019
sp_UserOfflineSmall Offline
1
September 19, 2019 - 7:32 pm
sp_Permalink sp_Print

Hi,

I have a question concerning the transformation of data into a table. I believe the solution is easy, but somehow I cannot get the clue. Having a sequence of headers in column1 with its value in column2. What I want to get is to transform Column1 into row headers and their records in rows below.

Input:

Column1 Column2
A               1
B               2
C               3
A               5
B               6
C               8

Desired output:

A    B      C

1    2      3 

5    3      8

Thanks, Pavel

Avatar
Catalin Bombea
Iasi, Romania
Admin
Level 10
Forum Posts: 1810
Member Since:
November 8, 2013
sp_UserOfflineSmall Offline
2
September 20, 2019 - 3:21 am
sp_Permalink sp_Print

Hi Pavel,

Try the attached file. The query looks like this:

let
Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content],
#"Renamed Columns" = Table.RenameColumns(Source,{{"Column1", "ID"},{"Column2","Value"}}),
#"Changed Type" = Table.TransformColumnTypes(#"Renamed Columns",{{"ID", type text}, {"Value", type text}}),
#"Grouped Rows" = Table.Group(#"Changed Type", {"ID"}, {{"Count", each _, type table [ Value=number]}}),
#"Extracted First Characters" = Table.TransformColumns(#"Grouped Rows", {{"Count", each Table.Transpose(Table.SelectColumns(_,{"Value"})) }}),
#"Expanded Count1" = Table.ExpandTableColumn(#"Extracted First Characters", "Count", Table.ColumnNames(Table.Combine(#"Extracted First Characters"[Count])), Table.ColumnNames(Table.Combine(#"Extracted First Characters"[Count]))),
#"Transposed Table1" = Table.Transpose(#"Expanded Count1"),
#"Promoted Headers1" = Table.PromoteHeaders(#"Transposed Table1", [PromoteAllScalars=true])
in
#"Promoted Headers1"

Avatar
pav hun
Member
Members
Level 0
Forum Posts: 8
Member Since:
August 17, 2019
sp_UserOfflineSmall Offline
3
September 20, 2019 - 4:27 pm
sp_Permalink sp_Print

Hi Catalin,

thanks for the hint 🙂

Pavel

Avatar
Jim Chen
Member
Members

Power BI
Level 0
Forum Posts: 54
Member Since:
February 20, 2019
sp_UserOfflineSmall Offline
4
September 21, 2019 - 1:30 am
sp_Permalink sp_Print

Catalin,

I don't understand this step: #"Extracted First Characters"

Can you elaborate a bit?

Avatar
Catalin Bombea
Iasi, Romania
Admin
Level 10
Forum Posts: 1810
Member Since:
November 8, 2013
sp_UserOfflineSmall Offline
5
September 21, 2019 - 2:08 am
sp_Permalink sp_Print

If you move up one step, you will see that the grouping step created tables in the second column. You will notice that those tables from the second column has both columns from the original table, and we need just the second column. That's what that step does:

Table.SelectColumns(_,{"Value"})

I transposed the result so we can have the values in a horizontal table that can be expanded to the right, otherwise it will expand in rows, not in columns.

I confess I was lazy, you got me... I used one of the buttons from interface to extract first char, that's how the step #"Extracted First Characters" was originally created ( had something like each Text.First(_,1) , but i replaced it with each Table.Transpose(Table.SelectColumns(_,{"Value"})) )

Avatar
Jim Chen
Member
Members

Power BI
Level 0
Forum Posts: 54
Member Since:
February 20, 2019
sp_UserOfflineSmall Offline
6
September 22, 2019 - 8:56 am
sp_Permalink sp_Print

Catalin,

 

Really appreciated your patience. But I still stuck with this step: Extracted First Characters". I don't see adding a custom column with a formula nor do I see you use a custom button such as "Extract" because "Extract" was grayed out when I select "Table" column. I can't tell how you did it with this step from Power Query Editor.

 

Thanks!

Avatar
Catalin Bombea
Iasi, Romania
Admin
Level 10
Forum Posts: 1810
Member Since:
November 8, 2013
sp_UserOfflineSmall Offline
7
September 22, 2019 - 2:43 pm
sp_Permalink sp_Print

Use the Extract first character function on the first column, not the tables column...

Then change the column name and the function used in that step in the formula bar.

Avatar
Jim Chen
Member
Members

Power BI
Level 0
Forum Posts: 54
Member Since:
February 20, 2019
sp_UserOfflineSmall Offline
8
September 23, 2019 - 3:59 am
sp_Permalink sp_Print

Catalin,

Know why you used the button to extract the first character and then change the formula. Is the following an M language?

#"Extracted First Characters" = Table.TransformColumns(#"Grouped Rows", {{"Count", each Table.Transpose(Table.SelectColumns(_,{"Value"})) }}),

 

Thanks!

Avatar
Catalin Bombea
Iasi, Romania
Admin
Level 10
Forum Posts: 1810
Member Since:
November 8, 2013
sp_UserOfflineSmall Offline
9
September 23, 2019 - 2:15 pm
sp_Permalink sp_Print

Hi Jim,

Everything in Power Query is in M language, not sure what your question is about. The only difference is that some of the operations are exposed to the user interface (you just have to use the buttons) , for everything else not included in interface you have to design your own way to process data (write custom M code to perform custom operations).

sp_Feed
Go to top
Forum Timezone: Australia/Brisbane
Most Users Ever Online: 245
Currently Online: Kim Knox
Guest(s) 9
Currently Browsing this Page:
1 Guest(s)
Top Posters:
SunnyKow: 1432
Anders Sehlstedt: 871
Purfleet: 412
Frans Visser: 346
David_Ng: 306
lea cohen: 219
Jessica Stewart: 204
A.Maurizio: 202
Aye Mu: 201
jaryszek: 183
Newest Members:
Maria Conatser
Jefferson Granemann
Glen Coulthard
Nikki Fox
Rachele Dickie
Raj Mattoo
Mark Luke
terimeri dooriyan
Jack Aston
AndyC
Forum Stats:
Groups: 3
Forums: 24
Topics: 6221
Posts: 27285

 

Member Stats:
Guest Posters: 49
Members: 31908
Moderators: 3
Admins: 4
Administrators: Mynda Treacy, Philip Treacy, Catalin Bombea, FT
Moderators: MOTH Support, Velouria, Riny van Eekelen
© Simple:Press —sp_Information

Sidebar

Blog Categories

  • Excel
  • Excel Charts
  • Excel Dashboard
  • Excel Formulas
  • Excel PivotTables
  • Excel Shortcuts
  • Excel VBA
  • General Tips
  • Online Training
  • Outlook
  • Power Apps
  • Power Automate
  • Power BI
  • Power Pivot
  • Power Query
microsoft mvp logo
trustpilot excellent rating
Secured by Sucuri Badge
MyOnlineTrainingHub on YouTube Mynda Treacy on Linked In Mynda Treacy on Instagram Mynda Treacy on Twitter Mynda Treacy on Pinterest MyOnlineTrainingHub on Facebook
 

Company

  • About My Online Training Hub
  • Disclosure Statement
  • Frequently Asked Questions
  • Guarantee
  • Privacy Policy
  • Terms & Conditions
  • Testimonials
  • Become an Affiliate

Support

  • Contact
  • Forum
  • Helpdesk - For Technical Issues

Copyright © 2023 · My Online Training Hub · All Rights Reserved. Microsoft and the Microsoft Office logo are trademarks or registered trademarks of Microsoft Corporation in the United States and/or other countries. Product names, logos, brands, and other trademarks featured or referred to within this website are the property of their respective trademark holders.