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
Anonymous
Not applicable

Number client rows in table

Hello everyone,

 

I am trying to put an identifier per client. (like 1,2,3,4,5)

Over time a client can have multiple healthcare registrations

I am using the shanckey chart to visulize the patern(i am using the 1,2,3,4,5 from the clientcount column)

Now i am putting the numbers for every client manualy by hand

 

I want ot automate this process

Below 4 colums that is use.

Clientcount is the column i manually proces by hand in excel.

i am sorting the clientnumber and the begindate and then the proces starts to fill the clientcount column per client.

 

Is there a way to automatically fill the count number per client?

 

ClientnumberClientcountBegin dateEnd date
16205120-08-201809-12-2018
16205210-12-201807-04-2019
16205308-04-201906-10-2019
16205407-10-201922-12-2019
16214131-12-201829-12-2019
16214203-02-202031-01-2021
16218130-04-201827-01-2019
16218216-12-201913-12-2020

 

2 ACCEPTED SOLUTIONS
Mariusz
Community Champion
Community Champion

Hi @Anonymous 

 

Try this script or see the attached.

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("bY7BDcMwDAN38TsCSDm141kC779GqTpVU7TPI46UzrOwOR5lKw7DYQ4eAgyjL5jbxyEyltMNe8D4cjTyjgXN1Pl1esY67NdoOtwVV95u+fjroBoidqwCGMB0olpx/fPa6cu57UTMlvOCukCjcz4B", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type text) meta [Serialized.Text = true]) in type table [Clientnumber = _t, #"Begin date" = _t, #"End date" = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Clientnumber", Int64.Type}, {"Begin date", type date}, {"End date", type date}}),
    #"Grouped Rows" = Table.Group(#"Changed Type", {"Clientnumber"}, {{"tbl", each  
        let 
            tbl = _,
            #"Sorted Rows" = Table.Sort( tbl, {{ "End date", Order.Ascending } } ),
            #"Added Index" = Table.AddIndexColumn(#"Sorted Rows", "Clientcount", 1, 1)
        in 
            #"Added Index", type table }}),
    #"Expanded tbl" = Table.ExpandTableColumn(#"Grouped Rows", "tbl", {"Begin date", "End date", "Clientcount"}, {"Begin date", "End date", "Clientcount"}),
    #"Changed Type1" = Table.TransformColumnTypes(#"Expanded tbl",{{"Begin date", type date}, {"End date", type date}, {"Clientcount", Int64.Type}})
in
    #"Changed Type1"

 

Best Regards,
Mariusz

If this post helps, then please consider Accepting it as the solution.

Please feel free to connect with me.
LinkedIn

 

View solution in original post

dax
Community Support
Community Support

Hi @Anonymous , 

You could refer to @Mariusz 's suggestions, and you also could refer to my sample for details.

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("bY7BDcMwDAN38TsCSDm141kC779GqTpVU7TPI46UzrOwOR5lKw7DYQ4eAgyjL5jbxyEyltMNe8D4cjTyjgXN1Pl1esY67NdoOtwVV95u+fjroBoidqwCGMB0olpx/fPa6cu57UTMlvOCukCjcz4B", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type text) meta [Serialized.Text = true]) in type table [Clientnumber = _t, #"Begin date" = _t, #"End date" = _t]),
    #"Replaced Value" = Table.ReplaceValue(Source,"-",".",Replacer.ReplaceText,{"Begin date", "End date"}),
    #"Changed Type with Locale" = Table.TransformColumnTypes(#"Replaced Value", {{"Begin date", type date}, {"End date", type date}}, "sq-AL"),
    #"Grouped Rows" = Table.Group(#"Changed Type with Locale", {"Clientnumber"}, {{"all", each _, type table [Clientnumber=text, Begin date=date, End date=date]}}),
    #"Added Custom" = Table.AddColumn(#"Grouped Rows", "client count", each Table.AddIndexColumn([all], "client count", 1,1)),
    #"Removed Columns" = Table.RemoveColumns(#"Added Custom",{"all"}),
    #"Expanded client count" = Table.ExpandTableColumn(#"Removed Columns", "client count", {"Begin date", "End date", "client count"}, {"Begin date", "End date", "client count.1"})
in
    #"Expanded client count"

Best Regards,
Zoe Zhi

If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

View solution in original post

2 REPLIES 2
dax
Community Support
Community Support

Hi @Anonymous , 

You could refer to @Mariusz 's suggestions, and you also could refer to my sample for details.

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("bY7BDcMwDAN38TsCSDm141kC779GqTpVU7TPI46UzrOwOR5lKw7DYQ4eAgyjL5jbxyEyltMNe8D4cjTyjgXN1Pl1esY67NdoOtwVV95u+fjroBoidqwCGMB0olpx/fPa6cu57UTMlvOCukCjcz4B", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type text) meta [Serialized.Text = true]) in type table [Clientnumber = _t, #"Begin date" = _t, #"End date" = _t]),
    #"Replaced Value" = Table.ReplaceValue(Source,"-",".",Replacer.ReplaceText,{"Begin date", "End date"}),
    #"Changed Type with Locale" = Table.TransformColumnTypes(#"Replaced Value", {{"Begin date", type date}, {"End date", type date}}, "sq-AL"),
    #"Grouped Rows" = Table.Group(#"Changed Type with Locale", {"Clientnumber"}, {{"all", each _, type table [Clientnumber=text, Begin date=date, End date=date]}}),
    #"Added Custom" = Table.AddColumn(#"Grouped Rows", "client count", each Table.AddIndexColumn([all], "client count", 1,1)),
    #"Removed Columns" = Table.RemoveColumns(#"Added Custom",{"all"}),
    #"Expanded client count" = Table.ExpandTableColumn(#"Removed Columns", "client count", {"Begin date", "End date", "client count"}, {"Begin date", "End date", "client count.1"})
in
    #"Expanded client count"

Best Regards,
Zoe Zhi

If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

Mariusz
Community Champion
Community Champion

Hi @Anonymous 

 

Try this script or see the attached.

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("bY7BDcMwDAN38TsCSDm141kC779GqTpVU7TPI46UzrOwOR5lKw7DYQ4eAgyjL5jbxyEyltMNe8D4cjTyjgXN1Pl1esY67NdoOtwVV95u+fjroBoidqwCGMB0olpx/fPa6cu57UTMlvOCukCjcz4B", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type text) meta [Serialized.Text = true]) in type table [Clientnumber = _t, #"Begin date" = _t, #"End date" = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Clientnumber", Int64.Type}, {"Begin date", type date}, {"End date", type date}}),
    #"Grouped Rows" = Table.Group(#"Changed Type", {"Clientnumber"}, {{"tbl", each  
        let 
            tbl = _,
            #"Sorted Rows" = Table.Sort( tbl, {{ "End date", Order.Ascending } } ),
            #"Added Index" = Table.AddIndexColumn(#"Sorted Rows", "Clientcount", 1, 1)
        in 
            #"Added Index", type table }}),
    #"Expanded tbl" = Table.ExpandTableColumn(#"Grouped Rows", "tbl", {"Begin date", "End date", "Clientcount"}, {"Begin date", "End date", "Clientcount"}),
    #"Changed Type1" = Table.TransformColumnTypes(#"Expanded tbl",{{"Begin date", type date}, {"End date", type date}, {"Clientcount", Int64.Type}})
in
    #"Changed Type1"

 

Best Regards,
Mariusz

If this post helps, then please consider Accepting it as the solution.

Please feel free to connect with me.
LinkedIn

 

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.