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
KevinGesquiere
Frequent Visitor

Table with measures over different periods

Is it possible to show a table with measures over different periods? It probably does, but how should I get started?

To be more precise, the data is coming from an orders table where we want an overview of the following measures.

 

                                                Last 6 months     Last 2 months      Last month

% open orders                            ....                         ....                         ....

% closed orders < 5days            ....                         ....                         ....

% closed orders 5 - 15 days       ....                         ....                         ....

% closed orders > 15days          ....                         ....                         ....

 

Thanks

1 ACCEPTED SOLUTION

Hi @KevinGesquiere,

 

Please check out the demo in the attachment.

1. These conditions aren't in the source table, we can create one.

Col                                            ID

% open orders 1
% closed orders < 5days 2
% closed orders 5 - 15 days 3
% closed orders > 15days 4

2. We also need a date table.

 

Calendar = CALENDARAUTO()

3. Don't establish relationships.

4. Add calculated column to calculate days.

DaysUsed = DATEDIFF([Orderdate], [DateOrderClosed],DAY)

5. Create three measures.

Last Months =
VAR typeID =
    MAX ( Table2[ID] )
RETURN
    IF (
        typeID = 1,
        CALCULATE (
            COUNT ( Table1[Id] ),
            FILTER (
                'Table1',
                ISBLANK ( Table1[DateOrderClosed] ) = TRUE ()
                    && Table1[Orderdate] >= EOMONTH ( TODAY (), -1 )
            )
        ),
        IF (
            typeID = 2,
            CALCULATE (
                COUNT ( Table1[Id] ),
                FILTER (
                    'Table1',
                    ISBLANK ( Table1[DateOrderClosed] ) = FALSE ()
                        && Table1[Orderdate] >= EOMONTH ( TODAY (), -1 )
                        && Table1[DateOrderClosed] <= TODAY ()
                        && 'Table1'[DaysUsed] < 5
                )
            ),
            IF (
                typeID = 3,
                CALCULATE (
                    COUNT ( Table1[Id] ),
                    FILTER (
                        'Table1',
                        ISBLANK ( Table1[DateOrderClosed] ) = FALSE ()
                            && Table1[Orderdate] >= EOMONTH ( TODAY (), -1 )
                            && Table1[DateOrderClosed] <= TODAY ()
                            && 'Table1'[DaysUsed] <= 15
                            && 'Table1'[DaysUsed] >= 5
                    )
                ),
                IF (
                    typeid = 4,
                    CALCULATE (
                        COUNT ( Table1[Id] ),
                        FILTER (
                            'Table1',
                            ISBLANK ( Table1[DateOrderClosed] ) = FALSE ()
                                && Table1[Orderdate] >= EOMONTH ( TODAY (), -1 )
                                && Table1[DateOrderClosed] <= TODAY ()
                                && 'Table1'[DaysUsed] > 15
                        )
                    ),
                    0
                )
            )
        )
    )

 

 

Last 6 Months =
VAR typeID =
    MAX ( Table2[ID] )
RETURN
    IF (
        typeID = 1,
        CALCULATE (
            COUNT ( Table1[Id] ),
            FILTER (
                'Table1',
                ISBLANK ( Table1[DateOrderClosed] ) = TRUE ()
                    && Table1[Orderdate] >= EOMONTH ( TODAY (), -6 )
            )
        ),
        IF (
            typeID = 2,
            CALCULATE (
                COUNT ( Table1[Id] ),
                FILTER (
                    'Table1',
                    ISBLANK ( Table1[DateOrderClosed] ) = FALSE ()
                        && Table1[Orderdate] >= EOMONTH ( TODAY (), -6 )
                        && Table1[DateOrderClosed] <= TODAY ()
                        && 'Table1'[DaysUsed] < 5
                )
            ),
            IF (
                typeID = 3,
                CALCULATE (
                    COUNT ( Table1[Id] ),
                    FILTER (
                        'Table1',
                        ISBLANK ( Table1[DateOrderClosed] ) = FALSE ()
                            && Table1[Orderdate] >= EOMONTH ( TODAY (), -6 )
                            && Table1[DateOrderClosed] <= TODAY ()
                            && 'Table1'[DaysUsed] <= 15
                            && 'Table1'[DaysUsed] >= 5
                    )
                ),
                IF (
                    typeid = 4,
                    CALCULATE (
                        COUNT ( Table1[Id] ),
                        FILTER (
                            'Table1',
                            ISBLANK ( Table1[DateOrderClosed] ) = FALSE ()
                                && Table1[Orderdate] >= EOMONTH ( TODAY (), -6 )
                                && Table1[DateOrderClosed] <= TODAY ()
                                && 'Table1'[DaysUsed] > 15
                        )
                    ),
                    0
                )
            )
        )
    )
Last 2 Months =
VAR typeID =
    MAX ( Table2[ID] )
RETURN
    IF (
        typeID = 1,
        CALCULATE (
            COUNT ( Table1[Id] ),
            FILTER (
                'Table1',
                ISBLANK ( Table1[DateOrderClosed] ) = TRUE ()
                    && Table1[Orderdate] >= EOMONTH ( TODAY (), -2 )
            )
        ),
        IF (
            typeID = 2,
            CALCULATE (
                COUNT ( Table1[Id] ),
                FILTER (
                    'Table1',
                    ISBLANK ( Table1[DateOrderClosed] ) = FALSE ()
                        && Table1[Orderdate] >= EOMONTH ( TODAY (), -2 )
                        && Table1[DateOrderClosed] <= TODAY ()
                        && 'Table1'[DaysUsed] < 5
                )
            ),
            IF (
                typeID = 3,
                CALCULATE (
                    COUNT ( Table1[Id] ),
                    FILTER (
                        'Table1',
                        ISBLANK ( Table1[DateOrderClosed] ) = FALSE ()
                            && Table1[Orderdate] >= EOMONTH ( TODAY (), -2 )
                            && Table1[DateOrderClosed] <= TODAY ()
                            && 'Table1'[DaysUsed] <= 15
                            && 'Table1'[DaysUsed] >= 5
                    )
                ),
                IF (
                    typeid = 4,
                    CALCULATE (
                        COUNT ( Table1[Id] ),
                        FILTER (
                            'Table1',
                            ISBLANK ( Table1[DateOrderClosed] ) = FALSE ()
                                && Table1[Orderdate] >= EOMONTH ( TODAY (), -2 )
                                && Table1[DateOrderClosed] <= TODAY ()
                                && 'Table1'[DaysUsed] > 15
                        )
                    ),
                    0
                )
            )
        )
    )

Best Regards,

Dale

 

Community Support Team _ Dale
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-jiascu-msft
Employee
Employee

Hi @KevinGesquiere,

 

Did it work?

 

Best Regards,

Dale

Community Support Team _ Dale
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
danb
Resolver I
Resolver I

@KevinGesquiere

Can you provide a sample of your data table?

@danb

It's just as an example, but here is some data (I'm not showing here all the fields from the original table). When the field DateOrderClosed is NULL then the order is still open.

 

IdOrderdateDateOrderClosed
11/05/201822/05/2018
210/05/20183/06/2018
32/06/20185/06/2018
45/06/2018NULL

 

Thanks

Hi @KevinGesquiere,

 

Please check out the demo in the attachment.

1. These conditions aren't in the source table, we can create one.

Col                                            ID

% open orders 1
% closed orders < 5days 2
% closed orders 5 - 15 days 3
% closed orders > 15days 4

2. We also need a date table.

 

Calendar = CALENDARAUTO()

3. Don't establish relationships.

4. Add calculated column to calculate days.

DaysUsed = DATEDIFF([Orderdate], [DateOrderClosed],DAY)

5. Create three measures.

Last Months =
VAR typeID =
    MAX ( Table2[ID] )
RETURN
    IF (
        typeID = 1,
        CALCULATE (
            COUNT ( Table1[Id] ),
            FILTER (
                'Table1',
                ISBLANK ( Table1[DateOrderClosed] ) = TRUE ()
                    && Table1[Orderdate] >= EOMONTH ( TODAY (), -1 )
            )
        ),
        IF (
            typeID = 2,
            CALCULATE (
                COUNT ( Table1[Id] ),
                FILTER (
                    'Table1',
                    ISBLANK ( Table1[DateOrderClosed] ) = FALSE ()
                        && Table1[Orderdate] >= EOMONTH ( TODAY (), -1 )
                        && Table1[DateOrderClosed] <= TODAY ()
                        && 'Table1'[DaysUsed] < 5
                )
            ),
            IF (
                typeID = 3,
                CALCULATE (
                    COUNT ( Table1[Id] ),
                    FILTER (
                        'Table1',
                        ISBLANK ( Table1[DateOrderClosed] ) = FALSE ()
                            && Table1[Orderdate] >= EOMONTH ( TODAY (), -1 )
                            && Table1[DateOrderClosed] <= TODAY ()
                            && 'Table1'[DaysUsed] <= 15
                            && 'Table1'[DaysUsed] >= 5
                    )
                ),
                IF (
                    typeid = 4,
                    CALCULATE (
                        COUNT ( Table1[Id] ),
                        FILTER (
                            'Table1',
                            ISBLANK ( Table1[DateOrderClosed] ) = FALSE ()
                                && Table1[Orderdate] >= EOMONTH ( TODAY (), -1 )
                                && Table1[DateOrderClosed] <= TODAY ()
                                && 'Table1'[DaysUsed] > 15
                        )
                    ),
                    0
                )
            )
        )
    )

 

 

Last 6 Months =
VAR typeID =
    MAX ( Table2[ID] )
RETURN
    IF (
        typeID = 1,
        CALCULATE (
            COUNT ( Table1[Id] ),
            FILTER (
                'Table1',
                ISBLANK ( Table1[DateOrderClosed] ) = TRUE ()
                    && Table1[Orderdate] >= EOMONTH ( TODAY (), -6 )
            )
        ),
        IF (
            typeID = 2,
            CALCULATE (
                COUNT ( Table1[Id] ),
                FILTER (
                    'Table1',
                    ISBLANK ( Table1[DateOrderClosed] ) = FALSE ()
                        && Table1[Orderdate] >= EOMONTH ( TODAY (), -6 )
                        && Table1[DateOrderClosed] <= TODAY ()
                        && 'Table1'[DaysUsed] < 5
                )
            ),
            IF (
                typeID = 3,
                CALCULATE (
                    COUNT ( Table1[Id] ),
                    FILTER (
                        'Table1',
                        ISBLANK ( Table1[DateOrderClosed] ) = FALSE ()
                            && Table1[Orderdate] >= EOMONTH ( TODAY (), -6 )
                            && Table1[DateOrderClosed] <= TODAY ()
                            && 'Table1'[DaysUsed] <= 15
                            && 'Table1'[DaysUsed] >= 5
                    )
                ),
                IF (
                    typeid = 4,
                    CALCULATE (
                        COUNT ( Table1[Id] ),
                        FILTER (
                            'Table1',
                            ISBLANK ( Table1[DateOrderClosed] ) = FALSE ()
                                && Table1[Orderdate] >= EOMONTH ( TODAY (), -6 )
                                && Table1[DateOrderClosed] <= TODAY ()
                                && 'Table1'[DaysUsed] > 15
                        )
                    ),
                    0
                )
            )
        )
    )
Last 2 Months =
VAR typeID =
    MAX ( Table2[ID] )
RETURN
    IF (
        typeID = 1,
        CALCULATE (
            COUNT ( Table1[Id] ),
            FILTER (
                'Table1',
                ISBLANK ( Table1[DateOrderClosed] ) = TRUE ()
                    && Table1[Orderdate] >= EOMONTH ( TODAY (), -2 )
            )
        ),
        IF (
            typeID = 2,
            CALCULATE (
                COUNT ( Table1[Id] ),
                FILTER (
                    'Table1',
                    ISBLANK ( Table1[DateOrderClosed] ) = FALSE ()
                        && Table1[Orderdate] >= EOMONTH ( TODAY (), -2 )
                        && Table1[DateOrderClosed] <= TODAY ()
                        && 'Table1'[DaysUsed] < 5
                )
            ),
            IF (
                typeID = 3,
                CALCULATE (
                    COUNT ( Table1[Id] ),
                    FILTER (
                        'Table1',
                        ISBLANK ( Table1[DateOrderClosed] ) = FALSE ()
                            && Table1[Orderdate] >= EOMONTH ( TODAY (), -2 )
                            && Table1[DateOrderClosed] <= TODAY ()
                            && 'Table1'[DaysUsed] <= 15
                            && 'Table1'[DaysUsed] >= 5
                    )
                ),
                IF (
                    typeid = 4,
                    CALCULATE (
                        COUNT ( Table1[Id] ),
                        FILTER (
                            'Table1',
                            ISBLANK ( Table1[DateOrderClosed] ) = FALSE ()
                                && Table1[Orderdate] >= EOMONTH ( TODAY (), -2 )
                                && Table1[DateOrderClosed] <= TODAY ()
                                && 'Table1'[DaysUsed] > 15
                        )
                    ),
                    0
                )
            )
        )
    )

Best Regards,

Dale

 

Community Support Team _ Dale
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
KevinGesquiere
Frequent Visitor

Is it possible to show a table with measures over different periods? It probably does, but how should I get started?

To be more precise, the data is coming from an orders table where we want an overview of the following measures.

 

                                                Last 6 months     Last 2 months      Last month

% open orders                            ....                         ....                         ....

% closed orders < 5days            ....                         ....                         ....

% closed orders 5 - 15 days       ....                         ....                         ....

% closed orders > 15days          ....                         ....                         ....

 

Thanks

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.