Reputation: 75
I need some help here. Below is a DAX query that I have copied over from Power BI into Power BI Report Builder. I'm looking to pass a parameter into this query for 'edw dim_paycom_amcs_location_xref'[Paycom_Location_Desc]. However, I'm not sure where to place it within the query. I've researched the heck out of this and no matter where I try to place it I receive errors. Can anyone help with this? Thank you very much.
// DAX Query
DEFINE
VAR __DS0FilterTable =
TREATAS({"2021"}, 'edw dimDate'[Year])
VAR __DS0FilterTable2 =
TREATAS({"August"}, 'edw dimDate'[MonthName])
VAR __DS0Core =
SUMMARIZECOLUMNS(
'edw dimDate'[MonthYear],
'edw dimDate'[Month],
'edw dim_paycom_amcs_location_xref'[Paycom_Location_Desc],
__DS0FilterTable,
__DS0FilterTable2,
"SumOvertime_Hours_by_Day", CALCULATE(SUM('PaycomHours'[Overtime_Hours_by_Day])),
"SumReg_Hours_by_Day", CALCULATE(SUM('PaycomHours'[Reg_Hours_by_Day])),
"Transportation", 'PaycomHours'[Transportation],
"Total_Inbound_Tons", 'PaycomHours'[Total Inbound Tons],
"Total_Inbound_Tons__excl_Yakima_", 'PaycomHours'[Total Inbound Tons (excl Yakima)],
"No_Operating_Days", 'edw dimDate'[No.Operating Days],
"Tonnage_Inbound__3rd_Party", 'PaycomHours'[Tonnage Inbound- 3rd Party],
"Tonnage_Inbound__Intercompany", 'PaycomHours'[Tonnage Inbound- Intercompany],
"Tonnage_Inbound___3rd_Party_Metal", 'PaycomHours'[Tonnage Inbound - 3rd Party Metal],
"Tonnage___Intercompany_Metal", 'PaycomHours'[Tonnage - Intercompany Metal],
"Tonnage___Intercompany_Hog_Fuel", 'PaycomHours'[Tonnage - Intercompany Hog Fuel],
"Tonnage___3rd_Party_Hog_Fuel", 'PaycomHours'[Tonnage - 3rd Party Hog Fuel],
"Total_Commodities_Volume_Sold", 'PaycomHours'[Total Commodities Volume Sold],
"Tonnage___Intercompany_Cardboard", 'PaycomHours'[Tonnage - Intercompany Cardboard],
"Tonnage___Intercompany_ALL", 'PaycomHours'[Tonnage - Intercompany ALL],
"Tonnage___3rd_Party_ALL", 'PaycomHours'[Tonnage - 3rd Party ALL]
)
VAR __DS0PrimaryWindowed =
TOPN(
501,
__DS0Core,
'edw dimDate'[Month],
1,
'edw dimDate'[MonthYear],
1,
'edw dim_paycom_amcs_location_xref'[Paycom_Location_Desc],
1
)
EVALUATE
__DS0PrimaryWindowed
ORDER BY
'edw dimDate'[Month],
'edw dimDate'[MonthYear],
'edw dim_paycom_amcs_location_xref'[Paycom_Location_Desc]
Upvotes: 3
Views: 7182
Reputation: 672
DAX pattern schematic that I use. No need to use RSCustomDaxFilter function and thus you can use DaxStudio to work on your querys. Hallelujah :}
/*
History
yyyymmdd aa build
Datasets
abbrev = workspace.dataset.table
Notes
+ etc
*/
EVALUATE
-- parse the parameter value lists ready for the main querys
VAR ParameterA = SUBSTITUTE (TRIM (SUBSTITUTE (@ParameterA, ",", "|")), "| ", "|" )
-- build the lists
VAR TableA =
FILTER (
SELECTCOLUMNS (
'table',
"column a", 'table '[column a],
"column b", 'table '[column b],
etc
),
-- column a, ParameterA
SWITCH (
TRUE (),
LEN (ParameterA) = 0, TRUE (), -- ignore
PATHCONTAINS (ParameterA, "All"), TRUE (), -- ignore
IF ( PATHCONTAINS ( ParameterA, "NA" ), -- NA parameter selection
IF ( [column a] IN
{"NA",
"0",
"Not Applicable",
"Select",
" ",
"",
BLANK()},
TRUE (), -- NA value found
IF ( PATHCONTAINS ( ParameterA, [column a] ),
TRUE (), -- direct match found
FALSE () -- out of scope condition
)
),
FALSE ()
),
TRUE (),
PATHCONTAINS ( ParameterA, [column a] ), TRUE (),
FALSE ()
) &&
etc
)
VAR TableB =
etc
-- join the lists
VAR Result =
NATURALINNERJOIN (TableA, TableB)
RETURN
Result
--ROW ( "ParameterA", """"& ParameterA &"""" ) -- parameter checker
ORDER BY
[column a] ASC,
[column b] ASC
/* testing framework daxstudio */
<Parameters etc
<Parameter>
<Name></Name>
<Value xsi:type="xsd:string"></Value>
</Parameter>
etc
</Parameters>
Parameter dax query example (department), the above pattern is your main dax query.
DEFINE
-- create summary table
VAR SummaryTableUnique =
-- distinct list of values, excluding 'blank's
FILTER (
DISTINCT (
VALUES ( 'Measure Benefit Master'[Dept ID] )
),
NOT [Dept ID] IN {
"NA",
"0",
"Not Applicable",
"Select",
" ",
"",
BLANK()
}
)
-- add sorting column
VAR SummaryTable =
ADDCOLUMNS (
SummaryTableUnique,
"Sort", 1
)
-- create All row
VAR AllTable =
DATATABLE (
"Dept ID", STRING,
"Sort", INTEGER,
{
{ "All", 0 }
}
)
-- create NA row
VAR NATable =
DATATABLE (
"Dept ID", STRING,
"Sort", INTEGER,
{
{ "NA", 0 }
}
)
-- sandwich together
VAR UnionTable1 = UNION ( SummaryTable, AllTable ) -- keep data lineage by doing SummaryTable first
VAR UnionTable2 = UNION ( UnionTable1, NATable )
EVALUATE
UnionTable2
ORDER BY
[Sort] ASC, -- sort All, NA first then all others
[Dept ID] ASC
enter code here
Upvotes: 1
Reputation: 71
I've struggled a lot with parameters with DAX in Report Builder. There are a few different approaches depending on what your needs are.
The first question, do you need users to be able to change the value of the parameter? If so, you will need to define it under "Parameters" in Report Data.
Next regardless of your previous answer, you need to define the parameter in your dataset.
If you are using a user-selectable parameter, then use the notation shown in the screenshot of [@User_Parameter_Name]. If you click into the function editor, you will see this corresponds to the VB.Net expression
=Parameters!User_Parameter_Name.Value
The second question is if you are entering the query directly into the Query box in the Dataset Properties. If you are just pasting your DAX from PBI into that box, then you should be good to go.
However, if you are using the Query Designer (and I can't blame you if you don't), then you need to do as you have already discovered and re-declare the parameter within the Query Designer.
The problem with the Query Parameters here is that they really struggle with defaulting to empty values... Also, when I have a parameter, Query Designer always seems to forget that I'm using DAX and not MDX every time I opened it.
But anyways, once you declare it here, then you can refer to them in the query itself.
Finally, if you need to pass a list of values instead of a single value, the only way I've gotten this to work is to use this strange, little-documented function RSCustomDaxFilter to create a filter table:
VAR MonthFilter=
SUMMARIZECOLUMNS (
'Month'[Month],
RSCustomDaxFilter(@MonthQP,EqualToCondition, [Month].[Month], String
)
I can make some inferences on how this function works; the Table.Field syntax and specifying the object type make me think at least modeled after VB.Net, but aside from examples of how to use it in pretty much only this exact scenario, I have yet to find any official documentation on how it works, and the best explanation is from Chris Webb's blog, back in 2019. Also, it loves to freeze when performing query preparation if you don't use the Query Designer!
Upvotes: 3
Reputation: 40204
I'd suggest the following:
DEFINE
VAR __DS0FilterTable =
TREATAS ( { "2021" }, 'edw dimDate'[Year] )
VAR __DS0FilterTable2 =
TREATAS ( { "August" }, 'edw dimDate'[MonthName] )
VAR __DS0FilterTable3 =
TREATAS ( { @Location }, 'edw dim_paycom_amcs_location_xref'[Paycom_Location_Desc] )
VAR __DS0Core =
SUMMARIZECOLUMNS (
'edw dimDate'[MonthYear],
'edw dimDate'[Month],
'edw dim_paycom_amcs_location_xref'[Paycom_Location_Desc],
__DS0FilterTable,
__DS0FilterTable2,
__DS0FilterTable3,
[... Remainder of query the same ...]
Be sure to map @Location
to your report parameter here:
Upvotes: 3