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

Get certified in Microsoft Fabric—for free! For a limited time, get a free DP-600 exam voucher to use by the end of 2024. Register now

Reply
Bravo89
Frequent Visitor

New Custom Column to Keep track of Status Change

Hello everyone,

I've been dealing with a problem for the past few days that I unfortunately can't seem to find a solution for. I hope you can help me on this.
I have this sample of my dataset where I have 4 different Keys, which have a Status for each Extraction Date. The Status are only 3 and can variate from "A", "B" and "C", without any specific order.


(Dataset in table mode)

KeyExtractionDateStatus
JJUYXB2764JSG59DVZ6221/06/2023B
JJUYXB2764JSG59DVZ6222/06/2023C
JJUYXB2764JSG59DVZ6223/06/2023C
JJUYXB2764JSG59DVZ6224/06/2023C
JJUYXB2764JSG59DVZ6225/06/2023B
JJUYXB2764JSG59DVZ6226/06/2023A
JJUYXB2764JSG59DVZ6227/06/2023A
JJUYXB2764JSG59DVZ6228/06/2023C
JJUYXB2764JSG59DVZ6229/06/2023C
JJUYXB2764JSG59DVZ6230/06/2023C
JJUYXB2764JSG59DVZ6201/07/2023C
JJUYXB2764JSG59DVZ6202/07/2023C
PO8326BDJ456QVZA42JDSI827/06/2023C
PO8326BDJ456QVZA42JDSI828/06/2023B
PO8326BDJ456QVZA42JDSI829/06/2023A
HGA8635SNGJG8735DXVBC7365GS25/06/2023C
HGA8635SNGJG8735DXVBC7365GS26/06/2023C
HGA8635SNGJG8735DXVBC7365GS27/06/2023B
JDSYEBV74825VBC67398DXNBCD6Y21/06/2023B
JDSYEBV74825VBC67398DXNBCD6Y22/06/2023C
JDSYEBV74825VBC67398DXNBCD6Y23/06/2023A


(Picture with the same dataset but with colours)

Original DatasetOriginal Dataset


I need to create 4 new columns (NrDays_Status_A, NrDays_Status_B, NrDays_Status_CNrDays_Status_B_or_C) where I would know by Key and Extraction Date how many consecutive days the Status was. Something like this:

(Dataset with Expected Outcome in table mode)

KeyyExtractionDateStatusNrDays_Status_ANrDays_Status_BNrDays_Status_CNrDays_Status_B_or_C
JJUYXB2764JSG59DVZ6221/06/2023B0101
JJUYXB2764JSG59DVZ6222/06/2023C0012
JJUYXB2764JSG59DVZ6223/06/2023C0023
JJUYXB2764JSG59DVZ6224/06/2023C0034
JJUYXB2764JSG59DVZ6225/06/2023B0105
JJUYXB2764JSG59DVZ6226/06/2023A1000
JJUYXB2764JSG59DVZ6227/06/2023A2000
JJUYXB2764JSG59DVZ6228/06/2023C0011
JJUYXB2764JSG59DVZ6229/06/2023C0022
JJUYXB2764JSG59DVZ6230/06/2023C0033
JJUYXB2764JSG59DVZ6201/07/2023C0044
JJUYXB2764JSG59DVZ6202/07/2023C0055
PO8326BDJ456QVZA42JDSI827/06/2023C0011
PO8326BDJ456QVZA42JDSI828/06/2023B0102
PO8326BDJ456QVZA42JDSI829/06/2023A1000
HGA8635SNGJG8735DXVBC7365GS25/06/2023C0011
HGA8635SNGJG8735DXVBC7365GS26/06/2023C0022
HGA8635SNGJG8735DXVBC7365GS27/06/2023B0103
JDSYEBV74825VBC67398DXNBCD6Y21/06/2023B0101
JDSYEBV74825VBC67398DXNBCD6Y22/06/2023C0012
JDSYEBV74825VBC67398DXNBCD6Y23/06/2023A1000

 

(Picture with the Expected Outcome but with colours)

Expected OutcomeExpected Outcome
Let me know if you need more information and thank you in advance for your help.

1 ACCEPTED SOLUTION
wdx223_Daniel
Super User
Super User

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("ldIxDsMgDAXQuzBnIIANjAEqWoa0FSpKGuX+1yhSpSRSpeBOf3mD/e1lYSm95skJjSrlCDaUNwrWMQXcmpqOrd0psjX9Oeo5p6CegkR7pp7LmkMLKQoCykxIQZqCDAXtjT/uRgp0ISnAZ3kPSqSQb+awIMXBVum5w62waxwMSshjTNFoCWEqzmuJEPPhTJ5o5R9W7ecPeb64opURUBVqaU2YRucDzr//28aHP27h7z/XKtYP", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Key = _t, ExtractionDate = _t, Status = _t]),
    Custom1 = Table.TransformColumns(Source,{"ExtractionDate",each Date.From(Number.From(_))}),
    StatusList={"A","B","C",{"B","C"}},
    StartValues=List.Repeat({0},List.Count(StatusList)),
    ColNames=List.Transform(StatusList,each "NrDays_Status_" & (if _ is text then _ else Text.Combine(_,"_or_"))),
    Custom2 = List.Accumulate(Table.ToRows(Custom1),{{},{},{}},(x,y)=>let a=if y{0}=x{1}{0}? and Date.AddDays(y{1},-1)=x{1}{1}? then x{2} else StartValues,b=List.Transform(List.Positions(StatusList),each Byte.From(if StatusList{_} is text then StatusList{_}=y{2} else List.Contains(StatusList{_},y{2}))+a{_}*Byte.From(if StatusList{_} is text then x{1}{2}?=y{2} else List.ContainsAll(StatusList{_},{x{1}{2}?,y{2}}))) in {x{0}&{y&b},y,b}),
    Custom3=#table(Table.ColumnNames(Source)&ColNames,Custom2{0})
in
    Custom3

wdx223_Daniel_0-1689129342338.png

 

View solution in original post

2 REPLIES 2
wdx223_Daniel
Super User
Super User

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("ldIxDsMgDAXQuzBnIIANjAEqWoa0FSpKGuX+1yhSpSRSpeBOf3mD/e1lYSm95skJjSrlCDaUNwrWMQXcmpqOrd0psjX9Oeo5p6CegkR7pp7LmkMLKQoCykxIQZqCDAXtjT/uRgp0ISnAZ3kPSqSQb+awIMXBVum5w62waxwMSshjTNFoCWEqzmuJEPPhTJ5o5R9W7ecPeb64opURUBVqaU2YRucDzr//28aHP27h7z/XKtYP", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Key = _t, ExtractionDate = _t, Status = _t]),
    Custom1 = Table.TransformColumns(Source,{"ExtractionDate",each Date.From(Number.From(_))}),
    StatusList={"A","B","C",{"B","C"}},
    StartValues=List.Repeat({0},List.Count(StatusList)),
    ColNames=List.Transform(StatusList,each "NrDays_Status_" & (if _ is text then _ else Text.Combine(_,"_or_"))),
    Custom2 = List.Accumulate(Table.ToRows(Custom1),{{},{},{}},(x,y)=>let a=if y{0}=x{1}{0}? and Date.AddDays(y{1},-1)=x{1}{1}? then x{2} else StartValues,b=List.Transform(List.Positions(StatusList),each Byte.From(if StatusList{_} is text then StatusList{_}=y{2} else List.Contains(StatusList{_},y{2}))+a{_}*Byte.From(if StatusList{_} is text then x{1}{2}?=y{2} else List.ContainsAll(StatusList{_},{x{1}{2}?,y{2}}))) in {x{0}&{y&b},y,b}),
    Custom3=#table(Table.ColumnNames(Source)&ColNames,Custom2{0})
in
    Custom3

wdx223_Daniel_0-1689129342338.png

 

Hello @wdx223_Daniel , first of all thank you very much for your help/answer/solution. This is exactly what I wanted.

I'm still trying to understand the "Custom2" step 😅, not wanting to abuse your generosity, could you would be possible to explain this step?

One more thing I explained that it would be for consecutive days but I forgot to mention that on weekends and holidays there are no extractions. That is, it is necessary to take into account the last day available before the current extraction day, but not necessarily -1 day.

Helpful resources

Announcements
November Carousel

Fabric Community Update - November 2024

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

Live Sessions with Fabric DB

Be one of the first to start using Fabric Databases

Starting December 3, join live sessions with database experts and the Fabric product team to learn just how easy it is to get started.

Las Vegas 2025

Join us at the Microsoft Fabric Community Conference

March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount! Early Bird pricing ends December 9th.

Nov PBI Update Carousel

Power BI Monthly Update - November 2024

Check out the November 2024 Power BI update to learn about new features.