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
Denis_Slav
Helper III
Helper III

How to calculate length of series

Hi all,

I'd like to know how many times was value greater then 0 and get this value in last record for each series. 

IDRaw Length
11 
212
3-1 
4-1 
5-1 
6-1 
711
8-1 
91 
1012

Table sorted by ID. 

How can i calculate it?

1 ACCEPTED SOLUTION
v-janeyg-msft
Community Support
Community Support

Hi, @Denis_Slav 

 

According to your description, this problem seems simple, but it is actually difficult. You can try to create a custom column in PQ.

Like this(PQ advanced editor):

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMlTSUdI1VIrViVYyQjCNgUwIywQhaAoXNIOzzBHSFnBBSzjL0ADCjAUA", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [ID = _t, Raw = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"ID", Int64.Type}, {"Raw", Int64.Type}}),
    Custom1 = Table.Group(#"Changed Type","Raw",{"Test",each _},0,(x,y)=>Number.From(x*y<0)),
    #"Added Custom" = Table.AddColumn(Custom1, "Custom", each if [Raw]=-1 
then null 
else if [Raw]=1
then Table.RowCount([Test])
else null),
    Custom2 = Table.TransformRows(
   #"Added Custom",
   each let mtest=Table.Max( _[Test],"ID")[ID],cst=_[Custom]
   in
   [Raw=_[Raw],Test=Table.AddColumn(_[Test],"Re",(x)=>if x[ID]=mtest then _[Custom] else null)]
),
    #"Converted to Table" = Table.FromList(Custom2, Splitter.SplitByNothing(), null, null, ExtraValues.Error),
    #"Expanded Column1" = Table.ExpandRecordColumn(#"Converted to Table", "Column1", {"Raw", "Test"}, {"Column1.Raw", "Column1.Test"}),
    #"Expanded Column1.Test" = Table.ExpandTableColumn(#"Expanded Column1", "Column1.Test", {"ID", "Raw", "Re"}, {"Column1.Test.ID", "Column1.Test.Raw", "Column1.Test.Re"}),
    #"Removed Columns" = Table.RemoveColumns(#"Expanded Column1.Test",{"Column1.Test.Raw"}),
    #"Reordered Columns" = Table.ReorderColumns(#"Removed Columns",{"Column1.Test.ID", "Column1.Raw", "Column1.Test.Re"}),
    #"Renamed Columns" = Table.RenameColumns(#"Reordered Columns",{{"Column1.Test.ID", "ID"}, {"Column1.Raw", "Raw"}, {"Column1.Test.Re", "Count1"}})
in
    #"Renamed Columns"

6.png7.png

If it doesn’t solve your problem, please feel free to ask me.

 

Best Regards

Janey Guo

 

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

5 REPLIES 5
v-janeyg-msft
Community Support
Community Support

Hi, @Denis_Slav 

 

According to your description, this problem seems simple, but it is actually difficult. You can try to create a custom column in PQ.

Like this(PQ advanced editor):

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMlTSUdI1VIrViVYyQjCNgUwIywQhaAoXNIOzzBHSFnBBSzjL0ADCjAUA", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [ID = _t, Raw = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"ID", Int64.Type}, {"Raw", Int64.Type}}),
    Custom1 = Table.Group(#"Changed Type","Raw",{"Test",each _},0,(x,y)=>Number.From(x*y<0)),
    #"Added Custom" = Table.AddColumn(Custom1, "Custom", each if [Raw]=-1 
then null 
else if [Raw]=1
then Table.RowCount([Test])
else null),
    Custom2 = Table.TransformRows(
   #"Added Custom",
   each let mtest=Table.Max( _[Test],"ID")[ID],cst=_[Custom]
   in
   [Raw=_[Raw],Test=Table.AddColumn(_[Test],"Re",(x)=>if x[ID]=mtest then _[Custom] else null)]
),
    #"Converted to Table" = Table.FromList(Custom2, Splitter.SplitByNothing(), null, null, ExtraValues.Error),
    #"Expanded Column1" = Table.ExpandRecordColumn(#"Converted to Table", "Column1", {"Raw", "Test"}, {"Column1.Raw", "Column1.Test"}),
    #"Expanded Column1.Test" = Table.ExpandTableColumn(#"Expanded Column1", "Column1.Test", {"ID", "Raw", "Re"}, {"Column1.Test.ID", "Column1.Test.Raw", "Column1.Test.Re"}),
    #"Removed Columns" = Table.RemoveColumns(#"Expanded Column1.Test",{"Column1.Test.Raw"}),
    #"Reordered Columns" = Table.ReorderColumns(#"Removed Columns",{"Column1.Test.ID", "Column1.Raw", "Column1.Test.Re"}),
    #"Renamed Columns" = Table.RenameColumns(#"Reordered Columns",{{"Column1.Test.ID", "ID"}, {"Column1.Raw", "Raw"}, {"Column1.Test.Re", "Count1"}})
in
    #"Renamed Columns"

6.png7.png

If it doesn’t solve your problem, please feel free to ask me.

 

Best Regards

Janey Guo

 

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

@v-janeyg-msft Thank you. I think it's great idea to group around [Raw] and count its lengrth. 

I'll try to use this logic in my report.

 

Thank you. 

Hi, @Denis_Slav 

 

Here is a solution with Dax. Also thanks my colleague @v-alq-msft.

Column = 
IF(
    [Raw]=-1,
    BLANK(),
    IF(
        [Raw]=1,
        var first = 
            CALCULATE(
                MAX('Table'[ID]),
                FILTER(
                    ALL('Table'),
                    [ID]<EARLIER('Table'[ID])&&
                    [Raw]=-1
                )
            )
        var f1 = 
        IF(
            ISBLANK(first),
            1,
            first+1
        )
        var last = 
            CALCULATE(
                MIN('Table'[ID]),
                FILTER(
                    ALL('Table'),
                    [ID]>EARLIER('Table'[ID])&&
                    [Raw]=-1
                )
            )
        var l1 = 
        IF(
            ISBLANK(last),
            MAX('Table'[ID]),
            last-1
        )
        return
        IF(
           [ID]=l1,
           l1-f1+1,
           BLANK()
        )
    )
)

 

Best Regards

Janey Guo

parry2k
Super User
Super User

@Denis_Slav I will find another way to tweak it but for now, add this measure and see if you get the result

Count = 
VAR  __currentId = MAX ( Series[ID] )
VAR __lastPostiiveId = CALCULATE ( MAX ( Series[ID] ), FILTER ( ALL ( Series ), Series[ID] < __currentId && Series[Raw ] > 0 ) )
VAR __nextPositiveId = CALCULATE ( MIN ( Series[ID] ), FILTER ( ALL ( Series ), Series[ID] > __currentId && Series[Raw ] > 0 ) )
VAR __checkNextPositiveId = __nextPositiveId <> __currentId + 1
VAR __startId = IF ( __lastPostiiveId <> __currentId - 1, __currentId, __lastPostiiveId )
VAR __result = 
IF ( 
    MAX ( [Raw ] ) > 0 && 
    NOT ISBLANK ( __lastPostiiveId ) && 
    __checkNextPositiveId, 
    COUNTROWS ( GENERATESERIES ( __startId, __currentId ) ) 
)
RETURN __result

 

 

 

parry2k_0-1610741772202.png

 

Check my latest blog post Year-2020, Pandemic, Power BI and Beyond to get a summary of my favourite Power BI feature releases in 2020

I would  Kudos if my solution helped. 👉 If you can spend time posting the question, you can also make efforts to give Kudos to whoever helped to solve your problem. It is a token of appreciation!

Visit us at https://perytus.com, your one-stop-shop for Power BI-related projects/training/consultancy.

 

 



Subscribe to the @PowerBIHowTo YT channel for an upcoming video on List and Record functions in Power Query!!

Learn Power BI and Fabric - subscribe to our YT channel - Click here: @PowerBIHowTo

If my solution proved useful, I'd be delighted to receive Kudos. When you put effort into asking a question, it's equally thoughtful to acknowledge and give Kudos to the individual who helped you solve the problem. It's a small gesture that shows appreciation and encouragement! ❤


Did I answer your question? Mark my post as a solution. Proud to be a Super User! Appreciate your Kudos 🙂
Feel free to email me with any of your BI needs.

@parry2k Unfortunatly it's not work correct. I change values in [Raw], and they give me maximum 2, when it should be 4 values. 

And I try to make this calculation in column, not in measure. 

2021-01-16_11-14-17.png

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.