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

Date parameter for filtering multiple tables

Hi Evereyone,

 

I have Dynamics NAV tables to join where some tables are imported from overseas. Because the internet connection over there is crappy i would like to dynamically filter the table (rows) based on a "From Date" parameter at the opening of the pbix file?

 

Ideally I would like to have a custom table with specific parameter values that are used in the filtering of other tables.

So i have a testtable like this:

let
    Source = Excel.Workbook(File.Contents("C:\Temp\BITEST.xlsx"), null, true),
    testTable_Sheet = Source{[Item="testTable",Kind="Sheet"]}[Data],
    #"Promoted Headers" = Table.PromoteHeaders(testTable_Sheet, [PromoteAllScalars=true]),
    #"Changed Type" = Table.TransformColumnTypes(#"Promoted Headers",{{"No_", Int64.Type}, {"Date", type date}, {"Description", type text}})
in
    #"Changed Type"

Which contains:

No_DateDescription
12329-09-17test 123
12403-10-17test 124
12505-10-17test 125

 

And would like to have a Parameters Table with something like this:

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WcivKz3VJLElV0lEyMNQ1NNA1NFeKjQUA", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type text) meta [Serialized.Text = true]) in type table [Parameter = _t, Value = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Parameter", type text}, {"Value", type date}})
in
    #"Changed Type"

Which contains:

ParameterValue
FromDate01-10-17

 

How can I filter the first table to only import rows where the Date > Parameter.FromDate ?

Or maybe there are better solutions.

 

The actual tables contain 30+ columns and 400K+ rows and only need about 10% of that in my Dashboard.

Thanks in advance.

Colin

1 ACCEPTED SOLUTION
ImkeF
Super User
Super User

You can also use single parameters in PowerBI, but a table works just as fine in my eyes. So assume your parameter table is called "Parameters" this code should work:

 

let
    Source = Excel.Workbook(File.Contents("C:\Temp\BITEST.xlsx"), null, true),
    testTable_Sheet = Source{[Item="testTable",Kind="Sheet"]}[Data],
    #"Promoted Headers" = Table.PromoteHeaders(testTable_Sheet, [PromoteAllScalars=true]),
    #"Changed Type" = Table.TransformColumnTypes(#"Promoted Headers",{{"No_", Int64.Type}, {"Date", type date}, {"Description", type text}}) #"Filtered Rows" = Table.SelectRows(#"Changed Type", each ([Date] >= Parameters{[Parameter="FromDate"]}[Value])) in #"Filtered Rows"

 

Imke Feldmann

www.TheBIccountant.com -- How to integrate M-code into your solution  -- Check out more PBI- learning resources here

 

 

Imke Feldmann (The BIccountant)

If you liked my solution, please give it a thumbs up. And if I did answer your question, please mark this post as a solution. Thanks!

How to integrate M-code into your solution -- How to get your questions answered quickly -- How to provide sample data -- Check out more PBI- learning resources here -- Performance Tipps for M-queries

View solution in original post

2 REPLIES 2
ImkeF
Super User
Super User

You can also use single parameters in PowerBI, but a table works just as fine in my eyes. So assume your parameter table is called "Parameters" this code should work:

 

let
    Source = Excel.Workbook(File.Contents("C:\Temp\BITEST.xlsx"), null, true),
    testTable_Sheet = Source{[Item="testTable",Kind="Sheet"]}[Data],
    #"Promoted Headers" = Table.PromoteHeaders(testTable_Sheet, [PromoteAllScalars=true]),
    #"Changed Type" = Table.TransformColumnTypes(#"Promoted Headers",{{"No_", Int64.Type}, {"Date", type date}, {"Description", type text}}) #"Filtered Rows" = Table.SelectRows(#"Changed Type", each ([Date] >= Parameters{[Parameter="FromDate"]}[Value])) in #"Filtered Rows"

 

Imke Feldmann

www.TheBIccountant.com -- How to integrate M-code into your solution  -- Check out more PBI- learning resources here

 

 

Imke Feldmann (The BIccountant)

If you liked my solution, please give it a thumbs up. And if I did answer your question, please mark this post as a solution. Thanks!

How to integrate M-code into your solution -- How to get your questions answered quickly -- How to provide sample data -- Check out more PBI- learning resources here -- Performance Tipps for M-queries

pbinewb
Frequent Visitor

Hi Imke,

 

Thanks for your solution.

Its works, so now i can extend the Parameters table with additional filters.

Beginning to see the advantages of PowerBI.

 

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.