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
Cdeyoung-1998
Regular Visitor

How to Query Sys.Tables to find the table name

Hello,

 

In PowerBi Advanced Editor, I want to run the sys.tables quuery first to get the table name.  Then I want to query that table.  Is this possible?

 

SELECT name
FROM sys.tables
WHERE create_date = (
SELECT Max(create_date) NEWEST_VERSION
FROM sys.tables
WHERE name like '%AvailabilityStatus%'
)
2 ACCEPTED SOLUTIONS
OwenAuger
Super User
Super User

Hi @Cdeyoung-1998 

Yes this is possible.

I would suggest modifying your query to include the Schema as well to avoid ambiguity.

Then use the results of the first query as inputs into a second query.

 

Try this M code in a new Power Query query:

(replace Server and Database values with appropriate values)

let
    Server = ".\SQLEXPRESS",
    Database = "OwenSandbox",
    TableList = Sql.Database(Server, Database, [Query="SELECT tables.name AS table_name#(lf)#(tab),schemas.name AS schema_name#(lf)FROM sys.tables AS tables#(lf)LEFT OUTER JOIN sys.schemas AS schemas ON tables.schema_id = schemas.schema_id#(lf)WHERE create_date = (#(lf)#(tab)#(tab)SELECT Max(create_date) NEWEST_VERSION#(lf)#(tab)#(tab)FROM sys.tables#(lf)#(tab)#(tab)WHERE name LIKE '%AvailabilityStatus%'#(lf)#(tab)#(tab))#(lf)", CreateNavigationProperties=false]),
    TableName = TableList[table_name]{0},
    SchemaName = TableList[schema_name]{0},
    NavigateToTable = Sql.Database(Server, Database){[Schema = SchemaName, Item=TableName]}[Data]
in
    NavigateToTable

 

Regards


Owen Auger
Did I answer your question? Mark my post as a solution!
Blog
Twitter
LinkedIn

View solution in original post

It worked perfectly.   I have never been so appreciative!!!!!  Thank you.  Getting this little query to work is saving us from having to build a bunch of other things planned.

View solution in original post

2 REPLIES 2
OwenAuger
Super User
Super User

Hi @Cdeyoung-1998 

Yes this is possible.

I would suggest modifying your query to include the Schema as well to avoid ambiguity.

Then use the results of the first query as inputs into a second query.

 

Try this M code in a new Power Query query:

(replace Server and Database values with appropriate values)

let
    Server = ".\SQLEXPRESS",
    Database = "OwenSandbox",
    TableList = Sql.Database(Server, Database, [Query="SELECT tables.name AS table_name#(lf)#(tab),schemas.name AS schema_name#(lf)FROM sys.tables AS tables#(lf)LEFT OUTER JOIN sys.schemas AS schemas ON tables.schema_id = schemas.schema_id#(lf)WHERE create_date = (#(lf)#(tab)#(tab)SELECT Max(create_date) NEWEST_VERSION#(lf)#(tab)#(tab)FROM sys.tables#(lf)#(tab)#(tab)WHERE name LIKE '%AvailabilityStatus%'#(lf)#(tab)#(tab))#(lf)", CreateNavigationProperties=false]),
    TableName = TableList[table_name]{0},
    SchemaName = TableList[schema_name]{0},
    NavigateToTable = Sql.Database(Server, Database){[Schema = SchemaName, Item=TableName]}[Data]
in
    NavigateToTable

 

Regards


Owen Auger
Did I answer your question? Mark my post as a solution!
Blog
Twitter
LinkedIn

It worked perfectly.   I have never been so appreciative!!!!!  Thank you.  Getting this little query to work is saving us from having to build a bunch of other things planned.

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.

Top Solution Authors
Top Kudoed Authors