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

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

Reply
marktvc
Helper I
Helper I

Add an "Active Record" column

Hi All,

I have a Table - RatePlan and 2 specifc Columns I'm focusing on:

 

UNIQLIN (Id from another table)

INSERTDATE (date)

 

The field UNIQLIN appears multiple times but with different dates in INSERTDATE.

 

At the Query level, I would like to add a "CURRENT_RECORD" Y/N field.

 

so it would like this

marktvc_0-1614158179864.png

 

 

 

1 ACCEPTED SOLUTION
Jimmy801
Community Champion
Community Champion

Hello @marktvc 

 

you can add a Group-function on your ID with 2 function. AllRows and MaxDate of your date-column.

After that expand your grouped table and check whether your date-column is the same as the MaxDate.

Here some code

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WclTSUTIw1TMw0jMyUIrVgQgYG+gZGCMLGBnoGcJVOAEFDC3QBYAqDMACsQA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [UNIQLIN = _t, INSERTDATE = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"UNIQLIN", type text}, {"INSERTDATE", type date}}, "de-DE"),
    #"Grouped Rows" = Table.Group(#"Changed Type", {"UNIQLIN"}, {{"MaxDate", each List.Max([INSERTDATE]), type date}, {"AllRows", each _, type table [UNIQLIN=text, INSERTDATE=date]}}),
    #"Expanded AllRows" = Table.ExpandTableColumn(#"Grouped Rows", "AllRows", {"INSERTDATE"}, {"INSERTDATE"}),
    #"Added Custom" = Table.AddColumn(#"Expanded AllRows", "CURRENT_RECORD", each if [MaxDate]=[INSERTDATE] then "Y" else "N"),
    #"Removed Columns" = Table.RemoveColumns(#"Added Custom",{"MaxDate"})
in
    #"Removed Columns"

transforms this

Jimmy801_0-1614172304769.png

 

into this

Jimmy801_1-1614172314787.png

 

Copy paste this code to the advanced editor in a new blank query to see how the solution works.

If this post helps or solves your problem, please mark it as solution (to help other users find useful content and to acknowledge the work of users that helped you)
Kudoes are nice too

Have fun

Jimmy

View solution in original post

5 REPLIES 5
Jimmy801
Community Champion
Community Champion

Hello @marktvc 

 

you can add a Group-function on your ID with 2 function. AllRows and MaxDate of your date-column.

After that expand your grouped table and check whether your date-column is the same as the MaxDate.

Here some code

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WclTSUTIw1TMw0jMyUIrVgQgYG+gZGCMLGBnoGcJVOAEFDC3QBYAqDMACsQA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [UNIQLIN = _t, INSERTDATE = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"UNIQLIN", type text}, {"INSERTDATE", type date}}, "de-DE"),
    #"Grouped Rows" = Table.Group(#"Changed Type", {"UNIQLIN"}, {{"MaxDate", each List.Max([INSERTDATE]), type date}, {"AllRows", each _, type table [UNIQLIN=text, INSERTDATE=date]}}),
    #"Expanded AllRows" = Table.ExpandTableColumn(#"Grouped Rows", "AllRows", {"INSERTDATE"}, {"INSERTDATE"}),
    #"Added Custom" = Table.AddColumn(#"Expanded AllRows", "CURRENT_RECORD", each if [MaxDate]=[INSERTDATE] then "Y" else "N"),
    #"Removed Columns" = Table.RemoveColumns(#"Added Custom",{"MaxDate"})
in
    #"Removed Columns"

transforms this

Jimmy801_0-1614172304769.png

 

into this

Jimmy801_1-1614172314787.png

 

Copy paste this code to the advanced editor in a new blank query to see how the solution works.

If this post helps or solves your problem, please mark it as solution (to help other users find useful content and to acknowledge the work of users that helped you)
Kudoes are nice too

Have fun

Jimmy

here is my revise code.  it isn't quite perfecet as it generates a duplicate to UniqLine (UniqLine.1).  

 

Thanks Jimmy for pointing me in the right direction.  

 

#"Grouped Rows" = Table.Group(dbo_CFRatePlan, {"UniqLine"}, {{"MaxDate", each List.Max([InsertedDate]), type date}, {"AllRows", each _, type table [UniqLine=text, InsertedDate=date, UniqCFRatePlan=text]}}),
#"Expanded AllRows" = Table.ExpandTableColumn(#"Grouped Rows", "AllRows", {"UniqLine", "InsertedDate", "UniqCFRatePlan"}, {"UniqLine.1", "InsertedDate", "UniqCFRatePlan"}),
#"Added Custom" = Table.AddColumn(#"Expanded AllRows", "CURRENT_RECORD", each if [MaxDate]=[InsertedDate] then "Y" else "N"),
#"Removed Columns" = Table.RemoveColumns(#"Added Custom",{"MaxDate"}),
#"Removed Columns1" = Table.RemoveColumns(#"Removed Columns",{"UniqLine.1"})
in
#"Removed Columns1"

@Jimmy801 

 

I'm getting this error on the reload of data

 

let
Source = CFRatePlan,
#"Detected Type Mismatches" = let
tableWithOnlyPrimitiveTypes = Table.SelectColumns(Source, Table.ColumnsOfType(Source, {type nullable number, type nullable text, type nullable logical, type nullable date, type nullable datetime, type nullable datetimezone, type nullable time, type nullable duration})),
recordTypeFields = Type.RecordFields(Type.TableRow(Value.Type(tableWithOnlyPrimitiveTypes))),
fieldNames = Record.FieldNames(recordTypeFields),
fieldTypes = List.Transform(Record.ToList(recordTypeFields), each [Type]),
pairs = List.Transform(List.Positions(fieldNames), (i) => {fieldNames{i}, (v) => if v = null or Value.Is(v, fieldTypes{i}) then v else error [Message = "The type of the value does not match the type of the column.", Detail = v], fieldTypes{i}})
in
Table.TransformColumns(Source, pairs),
#"Added Index" = Table.AddIndexColumn(#"Detected Type Mismatches", "Row Number" ,1),
#"Kept Errors" = Table.SelectRowsWithErrors(#"Added Index", {"UniqLine", "InsertedDate", "UniqCFRatePlan", "CURRENT_RECORD"}),
#"Reordered Columns" = Table.ReorderColumns(#"Kept Errors", {"Row Number", "UniqLine", "InsertedDate", "UniqCFRatePlan", "CURRENT_RECORD"})
in
#"Reordered Columns"

Jimmy801
Community Champion
Community Champion

Hello @marktvc 

 

the group-step itself doesn't make your data disappear. It has to function that contains complete grouped table and the MaxDate. So you have to change the Expand-column step, where you have to define the columns you want again to see. Just check out the step on the right side, you can change this step in the GUI.

 

Hope it helps

 

BR

 

Jimmy

 

 

Almost there,  I have a number of other columns which disappear in the "Group" step.  I would like to see these.

 

Helpful resources

Announcements
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

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.

Top Solution Authors
Top Kudoed Authors