Check your eligibility for this 50% exam voucher offer and join us for free live learning sessions to get prepared for Exam DP-700.
Get StartedDon't miss out! 2025 Microsoft Fabric Community Conference, March 31 - April 2, Las Vegas, Nevada. Use code MSCUST for a $150 discount. Prices go up February 11th. Register now.
Scenario:
The user wants to convert the formatted forms such as Image1 into line-by-line data details such as Image2. For a convenient data analysis later.
Image1
Image2
Expected result:
The data needs to be displayed with line-by-line just like as Image2:
Image2
Detailed steps:
Let us start from convert single formatted form first
Some columns are recognized as null, we don't need to care about them. We only need to know where the value of each column is. For example, Applicant’s name “Jack” is in the first row of Column2 (Index: 0), so as long as you read "[Column2]{0}" in this table, you can get the Applicant’ Name. Similarly, the corresponding Age is in the third line of Column4, you can get the age by reading "[Column2]{0}" ...The corresponding position as shown in below table as summarized the information:
Column Name |
Column Value |
Index |
Applicant's name |
Column2 |
0 |
Age |
Column4 |
0 |
Gender |
Column6 |
0 |
Graduated school |
Column2 |
1 |
Hobby |
Column4 |
1 |
Telephone |
Column6 |
1 |
Mailbox |
Column2 |
2 |
|
|
|
let
Source = Excel.Workbook(File.Contents("xxx\xx\xx\xx.xlsx"), null, true),
Sheet1_Sheet = Source{[Item="Sheet1",Kind="Sheet"]}[Data],
Updated_Sheet= #table(
{"Name of applicant","Age","Gender","Graduated school","Hobby","Telephone","Mailbox"},
{{Sheet1_Sheet[Column2]{0},Sheet1_Sheet[Column4]{0},Sheet1_Sheet[Column6]{0},Sheet1_Sheet[Column2]{1},
Sheet1_Sheet[Column4]{1},Sheet1_Sheet[Column6]{1},Sheet1_Sheet[Column2]{2}}}
)
in
Updated_Sheet
If we need to convert multiple formatted forms as show in below screenshot, what should we do?
Finally, the table as show in below screenshot:
Here we can optimize the part about column position information (that is, step 2, 4 and 5 above):
Column Name |
Column Value |
Index |
Applicant's name |
Column2 |
0 |
Age |
Column4 |
0 |
Gender |
Column6 |
0 |
Graduated school |
Column2 |
1 |
Hobby |
Column4 |
1 |
Telephone |
Column6 |
1 |
Mailbox |
Column2 |
2 |
trans=(t)=>
#table(
Mapping[Column Name],
{List.Transform(
Mapping[Column Name],
each Record.Field(
t{Mapping{[Column Name=_]}[Index]},Mapping{[Column Name=_]}[Column Value]
))})
The full applied codes as follow:
let
trans=(t)=>
#table(
Mapping[Column Name],
{List.Transform(
Mapping[Column Name],
each Record.Field(
t{Mapping{[Column Name=_]}[Index]},Mapping{[Column Name=_]}[Column Value]
)
) }
),
Source = Excel.Workbook(File.Contents("D:\Blogs\2021.1.9\Interviewer registration form.xlsx"), null, true),
#"Added Custom" = Table.AddColumn(Source, "Custom", each trans([Data])),
#"Expanded Custom" = Table.ExpandTableColumn(#"Added Custom", "Custom", Mapping[Column Name], Mapping[Column Name]),
#"Removed Other Columns" = Table.SelectColumns(#"Expanded Custom",Mapping[Column Name])
in
#"Removed Other Columns"
Hope this article helps everyone with similar questions here.
Author: Rena Ruan
Reviewer: Ula Huang, Kerry Wang
You must be a registered user to add a comment. If you've already registered, sign in. Otherwise, register and sign in.