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

Earn a 50% discount on the DP-600 certification exam by completing the Fabric 30 Days to Learn It challenge.

Reply
dphillips
Helper IV
Helper IV

Best practice for splitting columns with multiple, comma separated values

Just completed a survey with some students getting their feedback on wide reading. For 3 of the columns they were allowed to select multiple answers. See image below.

WideReading1.png

 

No problems spitting the columns into rows using the delimiter but, clearly, this will lead to many rows for each original row - eg row 1 would be 2 x 3 x 3. This then creates duplication when I am trying to do counts of these responses. For example, after splitting the first 2 columns we now have 6 rows of data and when I split the third column there will be 18 rows of data.

WideReading2.png

 

I simply would like to know the best way to shape my data to make getting accurate information out to teachers as easy and understandable as possible. Should I split the data into separate tables and link each table via studentid (which is one of the fields also provided in the survey) or do I keep it all in the one table etc etc. Can someone please tell me the best way to set up my data model. Thanks for any help.

1 ACCEPTED SOLUTION
Daryl-Lynch-Bzy
Resident Rockstar
Resident Rockstar

Hi @dphillips , great question.  Can I suggest that you Unpivot questions into rows, then split:

 

From:

DarylLynchBzy_0-1666823693489.png

To:

DarylLynchBzy_1-1666823731315.png

Here is the example code:

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WclTSUUrUUUjSUUgGsip0FCp1FKqALEMdBSOlWJ1oJSdCCpwJKXDBqyAWAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Student = _t, #"Question 1" = _t, #"Question 2" = _t, #"Question 3" = _t]),
    #"Unpivoted Columns" = Table.UnpivotOtherColumns(Source, {"Student"}, "Attribute", "Value"),
    #"Split Column by Delimiter" = Table.ExpandListColumn(Table.TransformColumns(#"Unpivoted Columns", {{"Value", Splitter.SplitTextByDelimiter(",", QuoteStyle.Csv), let itemType = (type nullable text) meta [Serialized.Text = true] in type {itemType}}}), "Value"),
    #"Trimmed Text" = Table.TransformColumns(#"Split Column by Delimiter",{{"Value", Text.Trim, type text}})
in
    #"Trimmed Text"

I would add a dimension tables for Student and Questions.  You can use CALCULATE( exp , KEEPFILTERS( Question = 1 ) ) in your DAX functions.

 

 

View solution in original post

2 REPLIES 2
dphillips
Helper IV
Helper IV

Thanks. I have followed these steps through keeping the dimension fields that I have in the able and unpivotting the rest. Makes sense and seems to be quite clear. Also created the dimension tables as you suggested and using these as filters. Just started creating some visuals. thanks so much for your help.

Daryl-Lynch-Bzy
Resident Rockstar
Resident Rockstar

Hi @dphillips , great question.  Can I suggest that you Unpivot questions into rows, then split:

 

From:

DarylLynchBzy_0-1666823693489.png

To:

DarylLynchBzy_1-1666823731315.png

Here is the example code:

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WclTSUUrUUUjSUUgGsip0FCp1FKqALEMdBSOlWJ1oJSdCCpwJKXDBqyAWAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Student = _t, #"Question 1" = _t, #"Question 2" = _t, #"Question 3" = _t]),
    #"Unpivoted Columns" = Table.UnpivotOtherColumns(Source, {"Student"}, "Attribute", "Value"),
    #"Split Column by Delimiter" = Table.ExpandListColumn(Table.TransformColumns(#"Unpivoted Columns", {{"Value", Splitter.SplitTextByDelimiter(",", QuoteStyle.Csv), let itemType = (type nullable text) meta [Serialized.Text = true] in type {itemType}}}), "Value"),
    #"Trimmed Text" = Table.TransformColumns(#"Split Column by Delimiter",{{"Value", Text.Trim, type text}})
in
    #"Trimmed Text"

I would add a dimension tables for Student and Questions.  You can use CALCULATE( exp , KEEPFILTERS( Question = 1 ) ) in your DAX functions.

 

 

Helpful resources

Announcements
LearnSurvey

Fabric certifications survey

Certification feedback opportunity for the community.

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.