The ultimate Microsoft Fabric, Power BI, Azure AI, and SQL learning event: Join us in Stockholm, September 24-27, 2024.
Save €200 with code MSCUST on top of early bird pricing!
Find everything you need to get certified on Fabric—skills challenges, live sessions, exam prep, role guidance, and more. Get started
I'm connecting to a SQL view which has a lot of rows. Most of the time when we view the data we're going to be most interested in the last week or twos worth of data. I created StartTime and EndTime parameters and have them filter out rows as part of the query. I'm beginning to suspect that it's not working how I thought it would though. I suspect what's happening is that Power BI is querying the entire SQL view, grabbing the first 100,000 (or whatever) rows returned, and then applying the filter. The result being that there are days' worth of rows not showing up in the Power BI report, but I can see them when doing a query in SQL Server Management Studio.
So is there a way to push the Power BI parameters, into the Source of the Power BI query, (a simple WHERE clause), to filter out the rows from the SQL query?
Solved! Go to Solution.
@jader3rd,
Change your codes to the following.
let SQLSource = (StartTime as datetime, EndTime as datetime) => let Source = Sql.Database("MF-APDM-Shared1AlwaysOnVIP.OBDStripeDedicated-Prod-Bn2.Bn2.ap.gbl,89", "MDP_EXOMI", [Query="SELECT CONVERT(DATE, [START_TIME]) AS Day, [ACTION_REASON], [CHECKFAILED], COUNT(*) AS Cnt FROM [dbo].[HAOpBcsFailed] WHERE [START_TIME] >= '"& DateTime.ToText(StartTime) & "' AND [START_TIME] <= '"& DateTime.ToText(EndTime)&"' GROUP BY CONVERT(DATE, [START_TIME]), [ACTION_REASON], [CHECKFAILED]"]) in Source in SQLSource
Regards,
Lydia
Hi @jader3rd,
Open Power BI Desktop, and choose “Get Data->Blank query”, then click Advanced Editor, paste the following code in it.
let SQLSource = (param1 as date, param2 as date) => let Source = Sql.Database("servername", "databasename", [Query="select * from viewname where DateColumn>='"& Date.ToText(param1) & "' and DateColumn <='" & Date.ToText(param2)&"'"]) in Source in SQLSource
Then you can enter parameter values and click “Invoke” button to generate filtered table.
Regards,
Lydia Zhang
I'm so excited that this could work.
This is what I have.
let SQLSource = (StartTime as datetime, EndTime as datetime) => let Source = Sql.Database("MF-APDM-Shared1AlwaysOnVIP.OBDStripeDedicated-Prod-Bn2.Bn2.ap.gbl,89", "MDP_EXOMI", [Query="SELECT CONVERT(DATE, [START_TIME]) AS Day, [ACTION_REASON], [CHECKFAILED], COUNT(*) AS Cnt FROM [dbo].[HAOpBcsFailed] WHERE [START_TIME] >= '"& Date.ToText(StartTime) & "' AND [START_TIME] <= '"& Date.ToText(EndTime)&"' GROUP BY CONVERT(DATE, [START_TIME]), [ACTION_REASON], [CHECKFAILED]"]) in Source in SQLSource
And here's the error
An error occurred in the ‘HAOpBcsFailedFunc’ query. Expression.Error: We cannot convert the value #datetime(2017, 5, 1, 0, 0, 0) to type Date.
Details:
Value=5/1/2017 12:00:00 AM
Type=Type
@jader3rd,
Change your codes to the following.
let SQLSource = (StartTime as datetime, EndTime as datetime) => let Source = Sql.Database("MF-APDM-Shared1AlwaysOnVIP.OBDStripeDedicated-Prod-Bn2.Bn2.ap.gbl,89", "MDP_EXOMI", [Query="SELECT CONVERT(DATE, [START_TIME]) AS Day, [ACTION_REASON], [CHECKFAILED], COUNT(*) AS Cnt FROM [dbo].[HAOpBcsFailed] WHERE [START_TIME] >= '"& DateTime.ToText(StartTime) & "' AND [START_TIME] <= '"& DateTime.ToText(EndTime)&"' GROUP BY CONVERT(DATE, [START_TIME]), [ACTION_REASON], [CHECKFAILED]"]) in Source in SQLSource
Regards,
Lydia
Hi,
In my case I need to get first parameter from Database itself which I can't have as inner query due to some Cosmos limitation.
SQL 1 - First query is to get the max of column value - select max(column) from table
SQL 2 - select * from table where id = Value received from first query
Thank you in advance
To show what I'm seeing, here are the numbers from Power BI desktop:
StartDate | Count of OP_ID |
5/1/2017 0:00 | 7599 |
5/2/2017 0:00 | 6510 |
5/3/2017 0:00 | 7687 |
5/4/2017 0:00 | 12801 |
5/5/2017 0:00 | 13200 |
5/6/2017 0:00 | 17838 |
5/7/2017 0:00 | 11555 |
5/8/2017 0:00 | 7494 |
5/9/2017 0:00 | 9311 |
5/10/2017 0:00 | 12743 |
5/11/2017 0:00 | 15495 |
5/12/2017 0:00 | 13319 |
5/13/2017 0:00 | 12553 |
5/14/2017 0:00 | 7402 |
And here are the numbers from a SQL query doing what I expect Power BI is doing. They are very different.
StartDate | C |
5/1/2017 | 128627 |
5/2/2017 | 113405 |
5/3/2017 | 139923 |
5/4/2017 | 180977 |
5/5/2017 | 170624 |
5/6/2017 | 261793 |
5/7/2017 | 150938 |
5/8/2017 | 61490 |
5/9/2017 | 144524 |
5/10/2017 | 134023 |
5/11/2017 | 173369 |
5/12/2017 | 174371 |
5/13/2017 | 231799 |
5/14/2017 | 174641 |
5/15/2017 | 112142 |
5/16/2017 | 167455 |
Join the community in Stockholm for expert Microsoft Fabric learning including a very exciting keynote from Arun Ulag, Corporate Vice President, Azure Data.
Check out the August 2024 Power BI update to learn about new features.
Learn from experts, get hands-on experience, and win awesome prizes.
User | Count |
---|---|
114 | |
80 | |
78 | |
44 | |
39 |
User | Count |
---|---|
150 | |
116 | |
68 | |
64 | |
58 |