Skip to main content
cancel
Showing results for 
Search instead for 
Did you mean: 

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

Reply
nexus2004
Frequent Visitor

Date sits above column header

Hello All,

 

I imported and Excel file into PowerBi. The file has sales, sales commission and commission percentage data, broken out by year and quarter. The problem is the year and quarter date sits above the column headers (see table below). How would I be able to bring the date  from above into a column so it can be in a table format?

 

   202009 YTD202009 YTD 201909 YTD201909 YTD 
RegionTypeCompanySalesSales CommissionCommission SalesSales CommissionCommission 
EastSUVFord4,081260.6%5,979550.9%
WestSUVFord4,652541.2%7,703420.5%
NorthSUVFord7,315250.3%3,058581.9%
SouthSUVFord6,369420.7%2,188653.0%
EastSUVGM5,265110.2%2,418512.1%
WestSUVGM3,173230.7%6,691230.3%
NorthSUVGM6,972640.9%2,721291.1%
SouthSUVGM8,366780.9%2,666813.0%

 

Thanks

1 ACCEPTED SOLUTION
mahoneypat
Employee
Employee

Here is one way to do it in the query editor.  To see how it works, just create a blank query, go to Advanced Editor, and replace the text there with the M code below. 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("jZFNT8MwDIb/SlWpt6iKndZJznyd4MAGCFU7VFoFk9g6reOwf4/tMFptPXCoXTt+8uZNmibPcvP3oUVrY/a+vL0s0irEyeqkyPKVafLn7mPT77hcnvYdp5t+u293J/5btF/dcM4Z97ebYUizY5H9f1DU7trhKJMvrxzv+8OaU2VsADkccbAlFZxqE32UXGsvFkq/dXM01SiTFQcoUWhvvHWyhkrXiX7qD8fPS9wbB6KBScgJ7oytg2wZdMtf8UX/fY2TcRRHJS84GghCkmzpSltcO394VI+oIwDKYmIrUGm9kBJmfCvrDHhxiG7UJUMRxp6bc60w8eXKeak6X64Ie1Q4qmeY86xwYMfyUD5MYdKePmNyvPoB", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Column1 = _t, Column2 = _t, Column3 = _t, Column4 = _t, Column5 = _t, Column6 = _t, Column7 = _t, Column8 = _t, Column9 = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Column1", type text}, {"Column2", type text}, {"Column3", type text}, {"Column4", type text}, {"Column5", type text}, {"Column6", type text}, {"Column7", type text}, {"Column8", type text}, {"Column9", type text}}),
    TimePeriod = List.Select(List.Distinct(Record.ToList(#"Changed Type"{0})), each _ <>" "),
    Custom1 = #"Changed Type",
    #"Removed Top Rows" = Table.Skip(Custom1,1),
    #"Promoted Headers" = Table.PromoteHeaders(#"Removed Top Rows", [PromoteAllScalars=true]),
    #"Changed Type1" = Table.TransformColumnTypes(#"Promoted Headers",{{"Region", type text}, {"Type", type text}, {"Company", type text}, {"Sales", Int64.Type}, {"Sales Commission", Int64.Type}, {"Commission ", Percentage.Type}, {"Sales_1", Int64.Type}, {"Sales Commission_2", Int64.Type}, {"Commission _3", Percentage.Type}}),
    #"Unpivoted Other Columns" = Table.UnpivotOtherColumns(#"Changed Type1", {"Region", "Type", "Company"}, "Attribute", "Value"),
    #"Extracted Text Before Delimiter" = Table.TransformColumns(#"Unpivoted Other Columns", {{"Attribute", each Text.BeforeDelimiter(_, "_"), type text}}),
    #"Grouped Rows" = Table.Group(#"Extracted Text Before Delimiter", {"Region", "Type", "Company", "Attribute"}, {{"Max", each Table.FromColumns({[Value], TimePeriod})}}),
    #"Expanded Max" = Table.ExpandTableColumn(#"Grouped Rows", "Max", {"Column1", "Column2"}, {"Column1", "Column2"}),
    #"Renamed Columns" = Table.RenameColumns(#"Expanded Max",{{"Column1", "Value"}, {"Column2", "Time Period"}}),
    #"Changed Type2" = Table.TransformColumnTypes(#"Renamed Columns",{{"Time Period", type text}, {"Value", type number}}),
    #"Pivoted Column" = Table.Pivot(#"Changed Type2", List.Distinct(#"Changed Type2"[Attribute]), "Attribute", "Value")
in
    #"Pivoted Column"

 

Regards,

Pat





Did I answer your question? Mark my post as a solution! Kudos are also appreciated!

To learn more about Power BI, follow me on Twitter or subscribe on YouTube.


@mahoneypa HoosierBI on YouTube


View solution in original post

2 REPLIES 2
mahoneypat
Employee
Employee

Here is one way to do it in the query editor.  To see how it works, just create a blank query, go to Advanced Editor, and replace the text there with the M code below. 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("jZFNT8MwDIb/SlWpt6iKndZJznyd4MAGCFU7VFoFk9g6reOwf4/tMFptPXCoXTt+8uZNmibPcvP3oUVrY/a+vL0s0irEyeqkyPKVafLn7mPT77hcnvYdp5t+u293J/5btF/dcM4Z97ebYUizY5H9f1DU7trhKJMvrxzv+8OaU2VsADkccbAlFZxqE32UXGsvFkq/dXM01SiTFQcoUWhvvHWyhkrXiX7qD8fPS9wbB6KBScgJ7oytg2wZdMtf8UX/fY2TcRRHJS84GghCkmzpSltcO394VI+oIwDKYmIrUGm9kBJmfCvrDHhxiG7UJUMRxp6bc60w8eXKeak6X64Ie1Q4qmeY86xwYMfyUD5MYdKePmNyvPoB", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Column1 = _t, Column2 = _t, Column3 = _t, Column4 = _t, Column5 = _t, Column6 = _t, Column7 = _t, Column8 = _t, Column9 = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Column1", type text}, {"Column2", type text}, {"Column3", type text}, {"Column4", type text}, {"Column5", type text}, {"Column6", type text}, {"Column7", type text}, {"Column8", type text}, {"Column9", type text}}),
    TimePeriod = List.Select(List.Distinct(Record.ToList(#"Changed Type"{0})), each _ <>" "),
    Custom1 = #"Changed Type",
    #"Removed Top Rows" = Table.Skip(Custom1,1),
    #"Promoted Headers" = Table.PromoteHeaders(#"Removed Top Rows", [PromoteAllScalars=true]),
    #"Changed Type1" = Table.TransformColumnTypes(#"Promoted Headers",{{"Region", type text}, {"Type", type text}, {"Company", type text}, {"Sales", Int64.Type}, {"Sales Commission", Int64.Type}, {"Commission ", Percentage.Type}, {"Sales_1", Int64.Type}, {"Sales Commission_2", Int64.Type}, {"Commission _3", Percentage.Type}}),
    #"Unpivoted Other Columns" = Table.UnpivotOtherColumns(#"Changed Type1", {"Region", "Type", "Company"}, "Attribute", "Value"),
    #"Extracted Text Before Delimiter" = Table.TransformColumns(#"Unpivoted Other Columns", {{"Attribute", each Text.BeforeDelimiter(_, "_"), type text}}),
    #"Grouped Rows" = Table.Group(#"Extracted Text Before Delimiter", {"Region", "Type", "Company", "Attribute"}, {{"Max", each Table.FromColumns({[Value], TimePeriod})}}),
    #"Expanded Max" = Table.ExpandTableColumn(#"Grouped Rows", "Max", {"Column1", "Column2"}, {"Column1", "Column2"}),
    #"Renamed Columns" = Table.RenameColumns(#"Expanded Max",{{"Column1", "Value"}, {"Column2", "Time Period"}}),
    #"Changed Type2" = Table.TransformColumnTypes(#"Renamed Columns",{{"Time Period", type text}, {"Value", type number}}),
    #"Pivoted Column" = Table.Pivot(#"Changed Type2", List.Distinct(#"Changed Type2"[Attribute]), "Attribute", "Value")
in
    #"Pivoted Column"

 

Regards,

Pat





Did I answer your question? Mark my post as a solution! Kudos are also appreciated!

To learn more about Power BI, follow me on Twitter or subscribe on YouTube.


@mahoneypa HoosierBI on YouTube


Pat,

 

Thank you that worked! M code is a bit above my calibur at this moment. Is there a more slimpified way to get the same output?

Helpful resources

Announcements
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

Check out the April 2024 Power BI update to learn about new features.

April Fabric Community Update

Fabric Community Update - April 2024

Find out what's new and trending in the Fabric Community.