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

Join us for an expert-led overview of the tools and concepts you'll need to become a Certified Power BI Data Analyst and pass exam PL-300. Register now.

Reply
LukeReds
Helper II
Helper II

Transform an horizontal table in vertical (3 columns) with Power Query

Hi to everyone,

I have a table like the one in the image above, every year there will be 3 new columns (name, description and a date), i need to trasform this table like the one below, only 3 columns with the date in all the cells of the 3td column

I can do it with vba but i need to use power query ( no dax)

 

Thank you in advance

 

tab.jpg

1 ACCEPTED SOLUTION
m_dekorte
Super User
Super User

Hi @LukeReds 

 

Give this a go. It assumes the same set of three columns is repeated in the exact same order.

let
    Source = YourTable,
    Split = Table.Combine( 
        List.Transform( 
            List.Split( Table.ColumnNames(Source), 3 ), each [
                t = Table.SelectColumns(Source, _),
                v = List.Last( Table.ColumnNames(t)),
                r = Table.FromColumns( 
                    List.RemoveLastN( Table.ToColumns(t), 1) 
                    & {List.Repeat( {v}, Table.RowCount(t))},
                    {"Name", "Description", "Date"}
                )
            ][r] 
        )
    )
in
    Split

 

with this result

m_dekorte_0-1721037732630.png

 

I hope this is helpful 

View solution in original post

5 REPLIES 5
dufoq3
Super User
Super User

Hi @LukeReds, 2 more solutions:

 

Result

dufoq3_0-1721308216043.png

 

v1

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WKi7JT842VNJRSkktTi5SgHOBCKdUrA5UnxGqpBGSPmxScH3GqJLGSPqwScH1maBKmiDpwyYF12eKKmmKpA+bVGwsAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [name = _t, description = _t, #"01/01/2000" = _t, name2 = _t, description2 = _t, #"01/01/2001" = _t]),
    ToCol = List.TransformMany(Table.ToRows(Source),
        each {List.Alternate(_, 1,2,2)},
        (x,y)=> {y{0}, y{1}, Table.ColumnNames(Source){2}, y{2}, y{3}, Table.ColumnNames(Source){5}} ),
    ToTbl = Table.Combine(List.Transform(List.Split(List.Zip(ToCol), 3), (x)=> Table.FromColumns(x, {"name", "description", "date"})))
in
    ToTbl

 

v2 - with this solution it doesn't matter how many pairs of columns do you have (i.e. you can have 5 pars of [Name], [Description] and [Date] columns)

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WKi7JT842VNJRSkktTi5SgHOBCKdUrA5UnxGqpBGSPmxScH3GqJLGSPqwScH1maBKmiDpwyYF12eKKmmKpA+bVGwsAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [name = _t, description = _t, #"01/01/2000" = _t, name2 = _t, description2 = _t, #"01/01/2001" = _t]),
    Ad_Helper = Table.AddColumn(Source, "Helper", each 
        [ a = Record.ToList(_),
          b = List.Alternate(a, 1, 2, 2), //name and description
          c = List.Alternate(Record.FieldNames(_), 2, 1), //every 3rd column name
          d = List.Split(b, 2), //splitted name and description
          e = List.Transform({ 0..List.Count(c)-1 }, (x)=> d{x} & {c{x}}) //combined name, descriptotion, 3rd column name
        ][e], type list),
    Helper = Table.Combine(List.Transform(List.Zip(Ad_Helper[Helper]), (x)=> Table.FromRows(x, {"name", "description", "date"})))
in
    Helper

 


Note: Check this link to learn how to use my query.
Check this link if you don't know how to provide sample data.

thank you  @dufoq3 

You're welcome.


Note: Check this link to learn how to use my query.
Check this link if you don't know how to provide sample data.

LukeReds
Helper II
Helper II

hi @m_dekorte 

super good solution, thank you!!!

m_dekorte
Super User
Super User

Hi @LukeReds 

 

Give this a go. It assumes the same set of three columns is repeated in the exact same order.

let
    Source = YourTable,
    Split = Table.Combine( 
        List.Transform( 
            List.Split( Table.ColumnNames(Source), 3 ), each [
                t = Table.SelectColumns(Source, _),
                v = List.Last( Table.ColumnNames(t)),
                r = Table.FromColumns( 
                    List.RemoveLastN( Table.ToColumns(t), 1) 
                    & {List.Repeat( {v}, Table.RowCount(t))},
                    {"Name", "Description", "Date"}
                )
            ][r] 
        )
    )
in
    Split

 

with this result

m_dekorte_0-1721037732630.png

 

I hope this is helpful 

Helpful resources

Announcements
July PBI25 Carousel

Power BI Monthly Update - July 2025

Check out the July 2025 Power BI update to learn about new features.

Join our Fabric User Panel

Join our Fabric User Panel

This is your chance to engage directly with the engineering team behind Fabric and Power BI. Share your experiences and shape the future.

June 2025 community update carousel

Fabric Community Update - June 2025

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