• 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

ExpandTableColumn with type text|Power Query|Excel Forum|My Online Training Hub

You are here: Home / ExpandTableColumn with type text|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 QueryExpandTableColumn with type text
sp_PrintTopic sp_TopicIcon
ExpandTableColumn with type text
Avatar
René Näf

Active Member
Members
Level 0
Forum Posts: 3
Member Since:
April 29, 2022
sp_UserOfflineSmall Offline
1
April 29, 2022 - 1:00 am
sp_Permalink sp_Print

Hi Mynda

I try to get data from more than one file in a folder.
Quelle = Folder.Files("..\002.350_2030456_d1"),
#"1" = Table.AddColumn(Quelle, "ExcelDateiinhalt", each Excel.Workbook([Content])),
#"2" = Table.ExpandTableColumn(#"1", "ExcelDateiinhalt", {"Data"}, {"ExcelDateiinhalt.Data"}),
#"3" = Table.AddColumn(#"2", "Header", each Table.PromoteHeaders([ExcelDateiinhalt.Data])),
#"4" = Table.ExpandTableColumn(#"3", "Header", {"partnb", "id"}, {"Header.partnb", "Header.id"}),
The Problem is with the ExpandTableColumn and the Header.id because I can't define it as txpe text (because it is a Serial No).
PowerQuery set type any automaticaly and 2030456.001 --> 2030456.0009999999 or 2030456.010 --> 2030456.01

any.jpgImage Enlarger

How can I set the type text before the table expand?

Ciao René

sp_PlupAttachments Attachments
  • sp_PlupImage any.jpg (8 KB)
Avatar
Mynda Treacy
Admin
Level 10
Forum Posts: 4446
Member Since:
July 16, 2010
sp_UserOfflineSmall Offline
2
May 1, 2022 - 3:58 pm
sp_Permalink sp_Print

Go to the Sample Query and change the data type there.

Mynda

Avatar
René Näf

Active Member
Members
Level 0
Forum Posts: 3
Member Since:
April 29, 2022
sp_UserOfflineSmall Offline
3
May 2, 2022 - 10:00 pm
sp_Permalink sp_Print

Thanks for you replay. I'm not sure if I understand you correctly, because I think there is no 'Sample Query'.

That's my current code:

let
Quelle = Folder.Files("Z:\data\002.350_2030456_d1"),
#"Hinzugefügte benutzerdefinierte Spalte" = Table.AddColumn(Quelle, "ExcelDateiinhalt", each Excel.Workbook([Content])),
#"Erweiterte ExcelDateiinhalt" = Table.ExpandTableColumn(#"Hinzugefügte benutzerdefinierte Spalte", "ExcelDateiinhalt", {"Data"}, {"ExcelDateiinhalt.Data"}),
#"Hinzugefügte benutzerdefinierte Spalte1" = Table.AddColumn(#"Erweiterte ExcelDateiinhalt", "Header", each Table.PromoteHeaders([ExcelDateiinhalt.Data])),
#"Erweiterte Header" = Table.ExpandTableColumn(#"Hinzugefügte benutzerdefinierte Spalte1", "Header", {"partnb", "id", "actual", "nominal", "deviation"}, {"Header.partnb", "Header.id", "Header.actual", "Header.nominal", "Header.deviation"}),
#"Gefilterte Zeilen" = Table.SelectRows(#"Erweiterte Header", each ([Header.partnb] <> null)),
#"Entfernte Spalten" = Table.RemoveColumns(#"Gefilterte Zeilen",{"Content", "Name", "Extension", "Date accessed", "Date modified", "Date created", "Attributes", "Folder Path", "ExcelDateiinhalt.Data"})
in
#"Entfernte Spalten"

Attached you will find 2 source files.

Avatar
Riny van Eekelen
Örnsköldsvik, Sweden
Moderator
Members


Trusted Members

Moderators

Power BI
Level 0
Forum Posts: 440
Member Since:
January 31, 2022
sp_UserOfflineSmall Offline
4
May 3, 2022 - 3:15 am
sp_Permalink sp_Print sp_EditHistory

You haven't really connected to files in a folder in the way it is meant to be. When you connect to a folder you should at some point expand the "binary" column. A number of helper queries will be generated automatically. One of them is the Sample Query where you do all the major transformations before you load all the files from the connected folder.

The concept is explained in the link below.

https://www.myonlinetraininghu.....m-a-folder

Then I noticed that the "partnb" columns in the source files actually contain the values that are extracted by PQ when you change the type to Text. Not sure where your source files come from or how they are created. Perhaps you can make sure that "partnb" is created as a text with three digits after the "."

Played around with your files a bit and came up with a few steps you could apply in case you can not change the format in the source files.

These are as follows (in English):

#"Rounded Off" = Table.TransformColumns(#"Previous Step",{{"partnb", each Number.Round(_, 3), type number}}),
#"Changed Type" = Table.TransformColumnTypes(#"Rounded Off",{{"partnb", type text}}),
#"Added Custom" = Table.AddColumn(#"Changed Type", "Custom", each Text.PadEnd ([partnb], 11, "0" ))

 

It rounds the part number to three digits, then changes the type to text and pads an extra zero ("0") in case there are only two digits in the part number after the point.

Perhaps you can get it to work on your end.

Avatar
Velouria
London or thereabouts
Moderator
Members


Trusted Members

Moderators
Level 4
Forum Posts: 615
Member Since:
November 1, 2018
sp_UserOfflineSmall Offline
5
May 3, 2022 - 9:00 pm
sp_Permalink sp_Print

Assuming the format is consistent, you could also use Number.ToText([Header.partnb],"F3")

Avatar
René Näf

Active Member
Members
Level 0
Forum Posts: 3
Member Since:
April 29, 2022
sp_UserOfflineSmall Offline
6
May 6, 2022 - 5:10 am
sp_Permalink sp_Print

Thanks so much for al your information and ideas.

Now, I understand again the way to use 'double down arrow on the Content column'. It generates this 'Sample Query' and other things. But it doesn't work for me when I change the data type there.

I use another solution for the same result with much less things. Only little code! Please have a look on it again (002.305.zip)
The only problem is with the Table.ExpandTableColumn where I can't set the data type!!!

I think your workaround with round and pad could work. Thanks for this workaround.

sp_Feed
Go to top
Forum Timezone: Australia/Brisbane
Most Users Ever Online: 245
Currently Online: Jeff Krueger, Shanna Henseler
Guest(s) 10
Currently Browsing this Page:
1 Guest(s)
Top Posters:
SunnyKow: 1432
Anders Sehlstedt: 870
Purfleet: 412
Frans Visser: 346
David_Ng: 306
lea cohen: 219
A.Maurizio: 202
Jessica Stewart: 202
Aye Mu: 201
jaryszek: 183
Newest Members:
John Chisholm
vexokeb sdfg
John Jack
Malcolm Toy
Ray-Yu Yang
George Shihadeh
Naomi Rumble
Uwe von Gostomski
Jonathan Jones
drsven
Forum Stats:
Groups: 3
Forums: 24
Topics: 6212
Posts: 27236

 

Member Stats:
Guest Posters: 49
Members: 31889
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.