Best way eliminate rows with multiple status from a count?

macfuller

Active Member
Joined
Apr 30, 2014
Messages
257
I receive data from our ERP system on vouchers that create errors. I want to have a measure that tells me how many voucher lines were closed within the last week. But... a voucher can create multiple errors - one might be closed during that week, but if the same line has an open error I don't want to count that toward the closed line total.

Voucher KeyFirst DateLast DateStatusError
POG_0556221_111/7/1911/9/19ClosedP400
POG_0556221_111/7/1911/11/19OpenR500
POG_0558442_211/8/1911/10/19ClosedE110

<tbody>
</tbody>




As of 11/12/19 these 3 lines would be part of a closed voucher line report.

In this example voucher 0556221 line 1 spun two errors, one of which is closed. All 3 records, 2 voucher lines, have a closed status within the last week, but because 0556221 line 1 still has an open error I don't want to count it as closed for the weekly status. The total of closed lines = 1 for voucher 0558442.

What is the best way to create this measure? I have little experience with UNION and INTERSECT. Perhaps SUMMARIZE based on the voucher key and status for the prior week, getting all voucher line counts then subtracting the count where status = Open?
 

Some videos you may like

Excel Facts

Repeat Last Command
Pressing F4 adds dollar signs when editing a formula. When not editing, F4 repeats last command.

sadath

Board Regular
Joined
Oct 10, 2004
Messages
244
Hi
Try this

Test :=
COUNTROWS (
FILTER (
ADDCOLUMNS (
VALUES ( Table1[Voucher Key] ),
"Open", COUNTROWS (
SUMMARIZE (
FILTER ( Table1, Table1[Status] = "OPEN" ),
Table1[Voucher Key],
Table1[First Date]
)
)
),
[Open] = 0
)
)
 

macfuller

Active Member
Joined
Apr 30, 2014
Messages
257
Sorry for the delay in responding, had to rebuild my date table.

The measure returns blanks for me.

VBA Code:
Test Closed Lines:=COUNTROWS (
    FILTER (
        ADDCOLUMNS (
            VALUES ( 'Match Exception'[ME_Key] ),
            "Open", COUNTROWS (
                SUMMARIZE (
                    FILTER (
                        'Match Exception',
                        'Match Exception'[ME Match Status] = "Open"
                    ),
                    'Match Exception'[ME_Key],
                    'Match Exception'[First Date]
                )
            )
        ),
        [Open] = 0
    )
)
I'll have to parse this in DAX Studio to see what's going on, but it looks worth the effort.
 

macfuller

Active Member
Joined
Apr 30, 2014
Messages
257
The ADDCOLUMNS "Open" column is returning the total of all Open items in the file rather than the # of open lines for that particular key combination. I've played around a bit but am not sure how to get it to return just a yes/no for whether there are any open lines for that combination. I suppose then I could add another column to get the number of closed lines along the same logic, and finally highlight vouchers that only have a value in the closed column?
 

macfuller

Active Member
Joined
Apr 30, 2014
Messages
257
OK, I played around with this and got some truly ugly code that returns the right number of rows in DAX Studio based on the number of rows returned. I am creating a table of 3 columns: voucher line, Open , Closed. If there is only a value in the Closed column then I know that no errors remain open against that line and I want to count that.

Code:
=
FILTER (
    ADDCOLUMNS (
        VALUES ( 'Match Exception'[ME_Key] ),
        "Open", COUNTROWS (
            SUMMARIZE (
                VAR MyKey = 'Match Exception'[ME_Key]
                RETURN
                    FILTER (
                        'Match Exception',
                        'Match Exception'[ME Match Status] = "Open"
                            && 'Match Exception'[ME_Key] = MyKey
                            && DATEDIFF (
                                'Match Exception'[Last Date],
                                [Last Match Date],
                                DAY
                            ) <= 7
                    ),
                'Match Exception'[ME_Key]
            )
        ),
        "Closed", COUNTROWS (
            SUMMARIZE (
                VAR MyKey = 'Match Exception'[ME_Key]
                RETURN
                    FILTER (
                        'Match Exception',
                        'Match Exception'[ME Match Status] = "Closed"
                            && 'Match Exception'[ME_Key] = MyKey
                            && DATEDIFF (
                                'Match Exception'[Last Date],
                                [Last Match Date],
                                DAY
                            ) <= 7
                    ),
                'Match Exception'[ME_Key]
            )
        )
    ),
    NOT (
        ISBLANK ( [Closed] )
    )
        && ISBLANK ( [Open] )
)
But... when I wrap a COUNTROWS around it, the measure crashes Excel 2016 64-bit... I mean, total reboot. Is there a way to make this cleaner so that I can get the result I want without dimming the lights in the Midwest?
 

Forum statistics

Threads
1,089,619
Messages
5,409,376
Members
403,260
Latest member
ssauk

This Week's Hot Topics

  • help please
    SORRY NOT ANY GOOD AT EXCEL SO HELP WOULD BE MUCH APPRECIATED this formula is in a sheet called ignore...
  • two formulas needed
    Hello, I'll try my best to explain this: First formula needed in Sheet1 cell A2: If Sheet1 cell B2 = Sheet2 cell B2 then return a 1. If not then...
  • Dynamic Counts
    Good afternoon, we are tidying up some data & the data seems to be growing quicker than we are tidying it up! What we confirm (by reviewing it...
  • Help Excel formula eliminate duplicate values and keep only 2 identical rows.
    as picture below column A has a duplicate value. but the values are not the same as the rule. sometimes 4 rows, sometimes 10 rows or 7 or 9...
  • Macro Compile Error Sub or Function not defined
    Hello, I am trying to run macros from a validation list, all macros have been created and run perfectly on there own but I'm getting a compile...
  • Last row combined with Current Region VBA
    I'm generally happy finding the last row of data through something like Lastrow = Cells(Rows.Count, "D").End(xlUp) but I don't always receive data...
Top