Home Power Query List.Repeat() in #PowerQuery to duplicate rows

List.Repeat() in #PowerQuery to duplicate rows

by Prathy Kamasani

Another quick, more of “Note to self” blog post. While I was working with FIFA Football Model, one of the queries has a dataset like below

But what I wanted was group every three rows into one group. So I can do further transformations to achieve a result like below.

So what have I done, I created a blank query to create my duplicate values. As I knew I needed eight groups, I created a base list in my blank query with following M

= {“a”..”h”}

Then I added a custom column with List.Repeat()

{List.Repeat({[Column1]},3)}

 

Then I added an index column which I used to join my base query, which gives me the following result after expanding.

Grouping values were easy with above state of data

Here is full M code:

Base Query

let

Source = #"2018 FIFA World Cup Wiki (2)",

#"Removed Other Columns" = Table.SelectColumns(Source,{"Column2"}),

#"Removed Duplicates" = Table.Distinct(#"Removed Other Columns"),

#"Promoted Headers" = Table.PromoteHeaders(#"Removed Duplicates", [PromoteAllScalars=true]),

#"Added Index" = Table.AddIndexColumn(#"Promoted Headers", "Index", 1, 1),

#"Merged Queries" = Table.NestedJoin(#"Added Index",{"Index"},Query1,{"Index"},"Query1",JoinKind.LeftOuter),

#"Expanded Query1" = Table.ExpandTableColumn(#"Merged Queries", "Query1", {"Custom"}, {"Custom"}),

#"Removed Other Columns1" = Table.SelectColumns(#"Expanded Query1",{"Custom", "Round of 16"}),

#"Renamed Columns" = Table.RenameColumns(#"Removed Other Columns1",{{"Round of 16", "R"}}),

#"Grouped Rows" = Table.Group(#"Renamed Columns", {"Custom"}, {{"Count", each [R], type table}}),

#"Added Custom" = Table.AddColumn(#"Grouped Rows", "Custom.1", each [Count]),

#"Extracted Values" = Table.TransformColumns(#"Added Custom", {"Custom.1", each Text.Combine(List.Transform(_, Text.From), ";"), type text}),

#"Split Column by Delimiter" = Table.SplitColumn(#"Extracted Values", "Custom.1", Splitter.SplitTextByDelimiter(";", QuoteStyle.Csv)),

#"Removed Columns" = Table.RemoveColumns(#"Split Column by Delimiter",{"Custom", "Count"})

in

#"Removed Columns"

Referenced Query

let

Source = {"a".."h"},

#"Converted to Table" = Table.FromList(Source, Splitter.SplitByNothing(), null, null, ExtraValues.Error),

#"Added Custom" = Table.AddColumn(#"Converted to Table", "Custom", each {List.Repeat({[Column1]},3)}),

#"Expanded Custom" = Table.ExpandListColumn(#"Added Custom", "Custom"),

#"Removed Other Columns" = Table.SelectColumns(#"Expanded Custom",{"Custom"}),

#"Expanded Custom1" = Table.ExpandListColumn(#"Removed Other Columns", "Custom"),

#"Added Index" = Table.AddIndexColumn(#"Expanded Custom1", "Index", 1, 1)

in

#"Added Index"

I genuinely feel like there must be an elegant way of grouping that data instead of creating another query, but then, this was the only way I could think off. Maybe with a bit of thinking, I could use List.Generate() to integrate and create duplicate values in the base query itself. Instead of using List.Repeat(), I can add a column by with list {1..3}, which also creates duplicate rows.Ā  Like any other language, there are various ways but, I used List.Repeat() the very first time, hence this blog post. Hope it helps someone out there šŸ™‚

Keep smiling,
Prathy šŸ™‚

You may also like

2 comments

Andrew Lindfield 6 July 2018 - 6:03 pm

Hi Prathy
Interesting solution. I hope the below answers your request for a more elegant solution. Sample data is included so just paste in to Power Query to test.
It uses an Index, Modulo (to assign rows to a column column), Integer divide (to group the rows) and Pivot.
This could easily be turned in to a function with just the table and number of repeating rows as input.

let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText(“HcXJDYAgAADBXnjbEeEhp4hyKli+yc5npBT7LtQmhdZkDFlLzpH3FAIdB8VI50kp0XXRfVPOVArVSq1R7zQGPQ+9L81Ja9H3CaV+”, BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type text) meta [Serialized.Text = true]) in type table [#”Round of 16″ = _t]),
#”Added Index” = Table.AddIndexColumn(Source, “Index”, 0, 1),
#”Inserted Modulo” = Table.AddColumn(#”Added Index”, “Modulo”, each Number.Mod([Index], 3), type number),
#”Integer-Divided Column” = Table.TransformColumns(#”Inserted Modulo”, {{“Index”, each Number.IntegerDivide(_, 3), Int64.Type}}),
#”Pivoted Column” = Table.Pivot(Table.TransformColumnTypes(#”Integer-Divided Column”, {{“Modulo”, type text}}, “en-GB”), List.Distinct(Table.TransformColumnTypes(#”Integer-Divided Column”, {{“Modulo”, type text}}, “en-GB”)[Modulo]), “Modulo”, “Round of 16″),
#”Removed Columns” = Table.RemoveColumns(#”Pivoted Column”,{“Index”}),
#”Renamed Columns” = Table.RenameColumns(#”Removed Columns”,{{“0”, “Date-Location”}, {“1”, “Home”}, {“2”, “Away”}})
in
#”Renamed Columns”

Reply
Prathy Kamasani 7 July 2018 - 6:16 am

Very nice, Thanks Andrew šŸ™‚

Reply

Leave a Reply

This site uses Akismet to reduce spam. Learn how your comment data is processed.