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

how to get the previous value taking into account other columns as a filter

DateValueTypeCategoryValue Before
1/1/2020 10.11A 
1/15/2020 10.22A 
2/2/2020 10.32B 
2/17/2020 10.42A 10.2
3/7/2020 10.52A 10.4
3/20/2020 10.61A 10.1 

 

I have an table like that and I need to get the value before taking into account the columns Type and Category. Realize that I don't have values for every day.

For example, if I'm analyzing the day 2/17/2020, the value is 10.4, type 2 and Category A. The Value Before this one has to be of the same type and category, so we need to take the 10.2 of the day 1/15/2020.

2 ACCEPTED SOLUTIONS
CNENFRNL
Community Champion
Community Champion

Value Before = 
VAR __d = MAX( INFO[Date] )
VAR __t =
    CALCULATETABLE(
        INFO,
        ALLEXCEPT( INFO, INFO[Category], INFO[Type] ),
        INFO[Date] < __d
    )
RETURN
    MAXX( TOPN( 1, __t, INFO[Date] ), INFO[Value] )

Screenshot 2021-07-08 212121.png


Thanks to the great efforts by MS engineers to simplify syntax of DAX! Most beginners are SUCCESSFULLY MISLED to think that they could easily master DAX; but it turns out that the intricacy of the most frequently used RANKX() is still way beyond their comprehension!

DAX is simple, but NOT EASY!

View solution in original post

v-yingjl
Community Support
Community Support

Hi @Anonymous ,

You can try this query:

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMtQ31DcyMDJQ0lFSMDTQMwTSIOyoFKsDljRFljUC0kZwWSN9I2RJY6ikE1TS0BxZ1gRFq7E+iqQpmqSRAbKsGcJNsQA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Date = _t, Value = _t, Type = _t, Category = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Date", type date}, {"Value", type number}, {"Type", Int64.Type}, {"Category", type text}}),
    #"Grouped Rows" = 
        Table.Group(
            #"Changed Type", {"Type", "Category"}, 
            {
                {"Data", 
                    each 
                    let tab = Table.AddIndexColumn(Table.Sort(_,{"Date",Order.Ascending}),"Index",1,1) in 
                    Table.AddColumn(
                        tab,"New",
                        (x) => try Table.Max(Table.SelectRows(tab,(y) => y[Index] = x[Index] - 1),"Index")[Value] otherwise null
                    ), 
                    type table [Date=nullable date, Value=nullable number, Type=nullable number, Category=nullable text]
                }
            }
        ),
    #"Removed Columns" = Table.RemoveColumns(#"Grouped Rows",{"Type", "Category"}),
    #"Expanded Data" = Table.ExpandTableColumn(#"Removed Columns", "Data", {"Date", "Value", "Type", "Category","New"}, {"Date", "Value", "Type", "Category","Value Before"}),
    #"Changed Type1" = Table.TransformColumnTypes(#"Expanded Data",{{"Date", type date}, {"Value", type number}, {"Type", Int64.Type}, {"Category", type text}, {"Value Before", type number}}),
    #"Sorted Rows" = Table.Sort(#"Changed Type1",{{"Date", Order.Ascending}})
in
    #"Sorted Rows"

previous.png

 

Best Regards,
Community Support Team _ Yingjie Li
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
v-yingjl
Community Support
Community Support

Hi @Anonymous ,

You can try this query:

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMtQ31DcyMDJQ0lFSMDTQMwTSIOyoFKsDljRFljUC0kZwWSN9I2RJY6ikE1TS0BxZ1gRFq7E+iqQpmqSRAbKsGcJNsQA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Date = _t, Value = _t, Type = _t, Category = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Date", type date}, {"Value", type number}, {"Type", Int64.Type}, {"Category", type text}}),
    #"Grouped Rows" = 
        Table.Group(
            #"Changed Type", {"Type", "Category"}, 
            {
                {"Data", 
                    each 
                    let tab = Table.AddIndexColumn(Table.Sort(_,{"Date",Order.Ascending}),"Index",1,1) in 
                    Table.AddColumn(
                        tab,"New",
                        (x) => try Table.Max(Table.SelectRows(tab,(y) => y[Index] = x[Index] - 1),"Index")[Value] otherwise null
                    ), 
                    type table [Date=nullable date, Value=nullable number, Type=nullable number, Category=nullable text]
                }
            }
        ),
    #"Removed Columns" = Table.RemoveColumns(#"Grouped Rows",{"Type", "Category"}),
    #"Expanded Data" = Table.ExpandTableColumn(#"Removed Columns", "Data", {"Date", "Value", "Type", "Category","New"}, {"Date", "Value", "Type", "Category","Value Before"}),
    #"Changed Type1" = Table.TransformColumnTypes(#"Expanded Data",{{"Date", type date}, {"Value", type number}, {"Type", Int64.Type}, {"Category", type text}, {"Value Before", type number}}),
    #"Sorted Rows" = Table.Sort(#"Changed Type1",{{"Date", Order.Ascending}})
in
    #"Sorted Rows"

previous.png

 

Best Regards,
Community Support Team _ Yingjie Li
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

CNENFRNL
Community Champion
Community Champion

Value Before = 
VAR __d = MAX( INFO[Date] )
VAR __t =
    CALCULATETABLE(
        INFO,
        ALLEXCEPT( INFO, INFO[Category], INFO[Type] ),
        INFO[Date] < __d
    )
RETURN
    MAXX( TOPN( 1, __t, INFO[Date] ), INFO[Value] )

Screenshot 2021-07-08 212121.png


Thanks to the great efforts by MS engineers to simplify syntax of DAX! Most beginners are SUCCESSFULLY MISLED to think that they could easily master DAX; but it turns out that the intricacy of the most frequently used RANKX() is still way beyond their comprehension!

DAX is simple, but NOT EASY!

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