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

Earn the coveted Fabric Analytics Engineer certification. 100% off your exam for a limited time only!

Reply
pointtoshare
Frequent Visitor

Convert few columns into rows in an existing table

Hi,

I have one table contains columns: A, B, C, D, E, F, G, H, I, J, K, L. I want to convert only E, F, G, H columns into rows . How can I go for it.

 

Thanks in advance.

1 ACCEPTED SOLUTION

Hi @pointtoshare,

 

If we Unpivot these 4 columns: E,F,G,H, we will get below result.  The other columns are still kept as original.  From the image which is your expected output, I am confused why each record repeats for three times.
3.PNG

 

To your second question"can I convert columns into rows in a calculated table", it is not available to pivot/unpivot a calculated table in query editor mode. However, to work around this issue, please try below DAX:

New Table =
UNION (
    SELECTCOLUMNS (
        'Convert column',
        "A", 'Convert column'[A],
        "Col1", "E",
        "Col2", 'Convert column'[E]
    ),
    SELECTCOLUMNS (
        'Convert column',
        "A", 'Convert column'[A],
        "Col1", "F",
        "Col2", 'Convert column'[F]
    ),
    SELECTCOLUMNS (
        'Convert column',
        "A", 'Convert column'[A],
        "Col1", "G",
        "Col2", 'Convert column'[G]
    ),
    SELECTCOLUMNS (
        'Convert column',
        "A", 'Convert column'[A],
        "Col1", "H",
        "Col2", 'Convert column'[H]
    )
)

4.PNG

 

Best regards,
Yuliana Gu

Community Support Team _ Yuliana Gu
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

View solution in original post

7 REPLIES 7
Anonymous
Not applicable

Your solution works perfectly, but how do I apply a filter using this solution

Sean
Community Champion
Community Champion

In the Query Editor

1) Select the 4 columns E, F, G, H

2) Transform tab - Unpivot Columns

3) Rename new columns as necessary

Hi Sean,

Thanks for your prompt reply.

The method you proposed is working but it breaks other columns setup as well. I want to keep other columns as it is. Is there any way to move the column E, F, G, H to another new table as table rows? Or, can I convert columns into rows in a calculated table?

 

Thanks.

Post sample data in its original format and then desired output from that data.

Hi Sean,

 

Here is my sample data table:

ABCDEFGHIJKL
Category1223344123455667788
Category2223344123455667788
Category3223344123455667788

 

And, here is my expected output:

ACol NameCol Name
Category1E1
Category1E1
Category1E1
Category1F2
Category1F2
Category1F2
Category1G3
Category1G3
Category1G3
Category1H4
Category1H4
Category1H4
Category2E1
Category2E1
Category2E1
Category2F2
Category2F2
Category2F2
………  

 

I want to convert only E, F, G, H Columns into Rows based on column A, keeping other columns as it is. Please let me know should you need any further clarifications.

 

Thanks.

Hi @pointtoshare,

 

If we Unpivot these 4 columns: E,F,G,H, we will get below result.  The other columns are still kept as original.  From the image which is your expected output, I am confused why each record repeats for three times.
3.PNG

 

To your second question"can I convert columns into rows in a calculated table", it is not available to pivot/unpivot a calculated table in query editor mode. However, to work around this issue, please try below DAX:

New Table =
UNION (
    SELECTCOLUMNS (
        'Convert column',
        "A", 'Convert column'[A],
        "Col1", "E",
        "Col2", 'Convert column'[E]
    ),
    SELECTCOLUMNS (
        'Convert column',
        "A", 'Convert column'[A],
        "Col1", "F",
        "Col2", 'Convert column'[F]
    ),
    SELECTCOLUMNS (
        'Convert column',
        "A", 'Convert column'[A],
        "Col1", "G",
        "Col2", 'Convert column'[G]
    ),
    SELECTCOLUMNS (
        'Convert column',
        "A", 'Convert column'[A],
        "Col1", "H",
        "Col2", 'Convert column'[H]
    )
)

4.PNG

 

Best regards,
Yuliana Gu

Community Support Team _ Yuliana Gu
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

Hi @v-yulgu-msft,

 

Thanks for your support. If I unpivot 4 columns other columns will remain same but the rows will be splitted based on the mentioned 4 columns value that's what I don't want to be. I want other columns value as a consolidated one the reason why I wan to unpivot these 4 columns in a separate table. Each record is not repeating three times, three 1s are different three values, I kept it same to mean it as a group.

 

Thanks for the DAX expression, I will try it and get back to you if it doesn't serve my purpose.

Helpful resources

Announcements
April AMA free

Microsoft Fabric AMA Livestream

Join us Tuesday, April 09, 9:00 – 10:00 AM PST for a live, expert-led Q&A session on all things Microsoft Fabric!

March Fabric Community Update

Fabric Community Update - March 2024

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