Find everything you need to get certified on Fabric—skills challenges, live sessions, exam prep, role guidance, and more. Get started
I have a table of Purchase Orders. One column in this table is listing specifier information and may contain anything like the below, which is a list of architects and engineers assigned to each order. I may have that column as blank, including a single specifier, or including several (and I can have multiple of the same type os specifier on a project as well)
Possible PO Table Specifier Column Results:
BLANK |
ENGINEER: [ENG NAME] |
ARCHITECT: [ARCH NAME] |
ARCHITECT: [ARCH NAME], ENGINEER: [ENGINEER NAME] |
ARCHITECT: [ARCH NAME], ENGINEER: [ENGINEER NAME], ENGINEER: [ENG NAME] |
I have a report showing a table of these orders and totaling them up. I also have a table of specifiers with a UserID assigned to it.
SPECIFIER | USERID |
CJD ENGINEERING | AREESE |
EXCEL | AREESE |
HBK ENGINEERING | AADRALES |
Then Finally, I have a table matching UserID's to Names
USERID | USER NAME |
AREESE | AARON REESE |
AADRALES | ABBY ADRALES |
ALUCIO | ABRIL LUCIO |
I have a report that shows tables with totals for PO's filtered by the last three years (one table for each year)
I need to be able to have a slicer of user names, then use that selection to end up filtering the PO table so I can see exactly how much business a user was tied to. I am not sure if I need to create a measure and use a CONTAINSSTRING function or what. With the way I am given the PO column for the specifier, I would need to filter the PO table based on whether that column contained the text string of ANY of the selected specifiers' names (a list that needs to be filterable by the user assigned to them). Right now, I have relationships between the specifiers table USERID column and the User table USERID column.
An example of the applicable rows in the PO table:
PO ABC | $5.00 | |
PO DEF | $10.00 | ARCHITECT: EXCEL |
PO GHI | $15.00 | ARCHITECT: EXCEL, ENGINEER: HBK ENGINEERING |
PO JKL | $20.00 | ENGINEER: HBK ENGINEERING |
PO MNO | $25.00 | ARCHITECT: EXCEL, ENGINEER: HBK ENGINEERING, ENGINEER: CJD ENGINEERING |
PO PQR | $30.00 | ARCHITECT: EXCEL |
PO STU | $35.00 | ENGINEER: HBK ENGINEERING, ENGINEER: CJD ENGINEERING |
PO VWX | $40.00 | ENGINEER: HBK ENGINEERING |
PO YZ | $45.00 | ENGINEER: CJD ENGINEERING |
I would want a Slicer that I could select Aaron Reese in, which would then filter the above table to only PO's that had CJD Engineering and/or Excel on it. In this case, returning PO DEF, GHI, JKL, MNO, PQR, STU, and YZ (all but the ABC which is blank and the VWX which does not contain one of aaron's specifiers.
Is this even possible?
Solved! Go to Solution.
Hi @TomWoodward ,
I created a sample pbix file(see the attachment), please find the details in it.
1. Create a measure as below
Flag =
VAR _userids =
ALLSELECTED ( 'Users'[USERID] )
VAR _specifiers =
CALCULATETABLE (
VALUES ( 'Specifiers'[SPECIFIER] ),
FILTER ( 'Specifiers', 'Specifiers'[USERID] IN _userids )
)
VAR _specifier =
MAX ( 'PO'[Specifier] )
VAR _spec1 =
SUBSTITUTE ( _specifier, "ARCHITECT: ", "" )
VAR _spec2 =
SUBSTITUTE ( _spec1, "ENGINEER: ", "" )
VAR mymeasure =
SUBSTITUTE ( _spec2, ", ", "|" )
VAR Mylen =
PATHLENGTH ( mymeasure )
VAR mytable =
ADDCOLUMNS (
GENERATESERIES ( 1, mylen ),
"mylist", PATHITEM ( mymeasure, [Value] )
)
VAR _specifiers2 =
SELECTCOLUMNS ( mytable, "list", [mylist] )
VAR _count =
COUNTROWS ( INTERSECT ( _specifiers, _specifiers2 ) )
RETURN
IF ( _count > 0, 1, 0 )
2. Create a visual and apply a visual-level filter with the condition(Flag is 1)
Best Regards
Hi @TomWoodward ,
I created a sample pbix file(see the attachment), please find the details in it.
1. Create a measure as below
Flag =
VAR _userids =
ALLSELECTED ( 'Users'[USERID] )
VAR _specifiers =
CALCULATETABLE (
VALUES ( 'Specifiers'[SPECIFIER] ),
FILTER ( 'Specifiers', 'Specifiers'[USERID] IN _userids )
)
VAR _specifier =
MAX ( 'PO'[Specifier] )
VAR _spec1 =
SUBSTITUTE ( _specifier, "ARCHITECT: ", "" )
VAR _spec2 =
SUBSTITUTE ( _spec1, "ENGINEER: ", "" )
VAR mymeasure =
SUBSTITUTE ( _spec2, ", ", "|" )
VAR Mylen =
PATHLENGTH ( mymeasure )
VAR mytable =
ADDCOLUMNS (
GENERATESERIES ( 1, mylen ),
"mylist", PATHITEM ( mymeasure, [Value] )
)
VAR _specifiers2 =
SELECTCOLUMNS ( mytable, "list", [mylist] )
VAR _count =
COUNTROWS ( INTERSECT ( _specifiers, _specifiers2 ) )
RETURN
IF ( _count > 0, 1, 0 )
2. Create a visual and apply a visual-level filter with the condition(Flag is 1)
Best Regards
This did work for me! thank you very much. But I do have a follow up question.
Now that I am able to have a visual for the PO's and a slicer for the user, I also need to be able to filter this table by year. There is a "date" column within the PO table that I have related to a "dates" table. Normally, I have been applying a filter to each visual to limit it to a certain year. This way, I can have a 2021, a 2022, and a 2023 visual that are all filtered by the user selected and the specifiers they call on.
When I set up these visuals as you have shown, then add a date filter to the visual, I get an error saying "MdxScript(Model) (115, 9) Calculation error in measure 'PO Listing 2009-Present'[Flag]: The arguments in GenerateSeries function cannot be blank", is there a way to fix this? or other way for me to create filtered by year visuals?
Check out the September 2024 Power BI update to learn about new features.
Learn from experts, get hands-on experience, and win awesome prizes.
User | Count |
---|---|
112 | |
93 | |
89 | |
35 | |
35 |
User | Count |
---|---|
154 | |
102 | |
82 | |
64 | |
54 |