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

The Power BI Data Visualization World Championships is back! Get ahead of the game and start preparing now! Learn more

Reply
neatdot
Helper I
Helper I

Creating SCD Type 2 with discontinuous repeating combinations

I have a dimension table as follows:

 

neatdot_0-1593701875328.png

 

I am using the following transformation to create a SCD Type 2:

 

 

 

let
    Source = ...,
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Key", Int64.Type}, {"Col1", type text}, {"Col2", Int64.Type}, {"Col3", type text}, {"Year", Int64.Type}}),
    #"Grouped Rows" = Table.Group(#"Changed Type", {"Key", "Col1", "Col2", "Col3"}, {{"From Year", each List.Min([Year]), type number}, {"To Year", each List.Max([Year]), type number}})
in
    #"Grouped Rows"

 

 

 

This results in the following:

 

neatdot_1-1593702099058.png

 

However, this is not correct. If you look at the original table, the combination of Col1 = "A", Col2 = 1, Col3 = "W" occurs in two periods, one from 2001 to 2002, and one from 2006 to 2006. These are being combined into a single row in the result above which overlaps with the from and to dates of the other records. How can I keep these as separate rows? In other words, I want to achieve this (correct) result instead:

 

2020-07-02_16-08-45.png

 

Any ideas how I can amend the M code to do this? I want to do the transformation in Power Query, rather than DAX.

 

Many thanks

1 ACCEPTED SOLUTION

Works perfectly! Thanks, @artemus 

View solution in original post

2 REPLIES 2
artemus
Microsoft Employee
Microsoft Employee

let
    Source = ...,
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Key", Int64.Type}, {"Col1", type text}, {"Col2", Int64.Type}, {"Col3", type text}, {"Year", Int64.Type}}),
    #"Added Custom" = Table.AddColumn(#"Changed Type", "From Year", each Function.ScalarVector(type function(X as record) as number, each List.Accumulate([X], {} meta [Key=null, Col1=null, Col2=null, Col3=null], (current, next) => (current & {if Value.Metadata(current)[[Key], [Col1], [Col2], [Col3]] = next[[Key], [Col1], [Col2], [Col3]] then Value.Metadata(current)[Year] else next[Year]}) meta next))(_), Int64.Type),
    #"Grouped Rows" = Table.Group(#"Added Custom", {"Key", "Col1", "Col2", "Col3", "From Year"}, {{"To Year", each List.Max([Year]), Int64.Type}})
in
    #"Grouped Rows"

Hopefully this works, I haven't tried Function.ScalarVector extensivly.

Works perfectly! Thanks, @artemus 

Helpful resources

Announcements
Power BI DataViz World Championships

Power BI Dataviz World Championships

The Power BI Data Visualization World Championships is back! Get ahead of the game and start preparing now!

December 2025 Power BI Update Carousel

Power BI Monthly Update - December 2025

Check out the December 2025 Power BI Holiday Recap!

FabCon Atlanta 2026 carousel

FabCon Atlanta 2026

Join us at FabCon Atlanta, March 16-20, for the ultimate Fabric, Power BI, AI and SQL community-led event. Save $200 with code FABCOMM.

Top Solution Authors