August 29, 2012 at 11:55 am
I have a table with 1 column (nvarchar(max)) that holds a list of distinct queries. Does anyone have a query that could go through that list and select all table names (not just the first one) from the queries?
create table #temp1 (query nvarchar(max))
insert into #temp1
values (' SELECT * FROM table1')
, (' SELECT col1, col23 FROM table2 a join table3 b on a.col1 = b.col1')
There is an exception to every rule, except this one...
August 29, 2012 at 12:29 pm
Unless the queries all strictly follow the same very simple format, this is going to fall somewhere between "Impossible" and "Incredibly Hard" to do in SQL.
If the queries are all truly valid (i.e., actually compilable, with tables and columns that actually exist in the database), then there is a way to do it the is merely "Very Difficult, Slow and Kludgy".
[font="Times New Roman"]-- RBarryYoung[/font], [font="Times New Roman"] (302)375-0451[/font] blog: MovingSQL.com, Twitter: @RBarryYoung[font="Arial Black"]
Proactive Performance Solutions, Inc. [/font][font="Verdana"] "Performance is our middle name."[/font]
August 29, 2012 at 12:35 pm
Ya, that's why I thought I might ask to see if anyone has done it, or is up to the challenge.:crazy:
There is an exception to every rule, except this one...
August 29, 2012 at 9:26 pm
Well, one thing that you could do if you were so inclined is to add the schema prefix (e.g., dbo.) to each referenced table in each query.
This is supposed to make a query a little more efficient (what I've read but never measured), but the important thing is that you could then use the schema prefix to parse out the table names.
As an example:
create table #temp1 (query nvarchar(max))
insert into #temp1
values (' SELECT * FROM dbo.table1')
, (' SELECT col1, col23 FROM dbo.table2 a join dbo.table3 b on a.col1 = b.col1')
;WITH rCTE (tablename, query, n) AS (
SELECT SUBSTRING(str1, 1, CHARINDEX(' ', str1 + ' '))
,SUBSTRING(str1, CHARINDEX(' ', str1 + ' '), 1+LEN(str1))
,n=ROW_NUMBER() OVER (ORDER BY (SELECT NULL))
FROM #temp1
CROSS APPLY (SELECT SUBSTRING(query, CHARINDEX('dbo.', query), LEN(query))) x (str1)
UNION ALL
SELECT SUBSTRING(str1, 1, CHARINDEX(' ', str1 + ' '))
,SUBSTRING(str1, CHARINDEX(' ', str1 + ' '), 1+LEN(str1)), n
FROM rCTE
CROSS APPLY (SELECT SUBSTRING(query, CHARINDEX('dbo.', query), LEN(query))) x (str1)
WHERE query <> '' AND SUBSTRING(str1, 1, CHARINDEX(' ', str1 + ' ')) <> '')
SELECT DISTINCT tablename
FROM rCTE
DROP TABLE #temp1
Should even be reasonably swift assuming your queries don't have 100 tables in each. π
My thought question: Have you ever been told that your query runs too fast?
My advice:
INDEXing a poor-performing query is like putting sugar on cat food. Yeah, it probably tastes better but are you sure you want to eat it?
The path of least resistance can be a slippery slope. Take care that fixing your fixes of fixes doesn't snowball and end up costing you more than fixing the root cause would have in the first place.
Need to UNPIVOT? Why not CROSS APPLY VALUES instead?[/url]
Since random numbers are too important to be left to chance, let's generate some![/url]
Learn to understand recursive CTEs by example.[/url]
[url url=http://www.sqlservercentral.com/articles/St
August 29, 2012 at 9:31 pm
RBarryYoung (8/29/2012)
Unless the queries all strictly follow the same very simple format, this is going to fall somewhere between "Impossible" and "Incredibly Hard" to do in SQL.If the queries are all truly valid (i.e., actually compilable, with tables and columns that actually exist in the database), then there is a way to do it the is merely "Very Difficult, Slow and Kludgy".
So Barry - what do you think of my suggestion?
Poll (select all that apply):
1. Impossible
2. Incredibly hard
3. Very Difficult
4. Slow
5. Kludgy
6. Clever
π
My thought question: Have you ever been told that your query runs too fast?
My advice:
INDEXing a poor-performing query is like putting sugar on cat food. Yeah, it probably tastes better but are you sure you want to eat it?
The path of least resistance can be a slippery slope. Take care that fixing your fixes of fixes doesn't snowball and end up costing you more than fixing the root cause would have in the first place.
Need to UNPIVOT? Why not CROSS APPLY VALUES instead?[/url]
Since random numbers are too important to be left to chance, let's generate some![/url]
Learn to understand recursive CTEs by example.[/url]
[url url=http://www.sqlservercentral.com/articles/St
August 30, 2012 at 5:51 am
Pretty clever dwain, thanks for your input!
There is an exception to every rule, except this one...
August 30, 2012 at 6:03 am
dwain.c (8/29/2012)
RBarryYoung (8/29/2012)
Unless the queries all strictly follow the same very simple format, this is going to fall somewhere between "Impossible" and "Incredibly Hard" to do in SQL.If the queries are all truly valid (i.e., actually compilable, with tables and columns that actually exist in the database), then there is a way to do it the is merely "Very Difficult, Slow and Kludgy".
So Barry - what do you think of my suggestion?
Poll (select all that apply):
1. Impossible
2. Incredibly hard
3. Very Difficult
4. Slow
5. Kludgy
6. Clever
π
4. Slow and 7. Tedious, going through all the queries adding "dbo." before each table name π π
For fast, accurate and documented assistance in answering your questions, please read this article.
Understanding and using APPLY, (I) and (II) Paul White
Hidden RBAR: Triangular Joins / The "Numbers" or "Tally" Table: What it is and how it replaces a loop Jeff Moden
August 30, 2012 at 6:21 am
ChrisM@Work (8/30/2012)
dwain.c (8/29/2012)
RBarryYoung (8/29/2012)
Unless the queries all strictly follow the same very simple format, this is going to fall somewhere between "Impossible" and "Incredibly Hard" to do in SQL.If the queries are all truly valid (i.e., actually compilable, with tables and columns that actually exist in the database), then there is a way to do it the is merely "Very Difficult, Slow and Kludgy".
So Barry - what do you think of my suggestion?
Poll (select all that apply):
1. Impossible
2. Incredibly hard
3. Very Difficult
4. Slow
5. Kludgy
6. Clever
π
4. Slow and 7. Tedious, going through all the queries adding "dbo." before each table name π π
Ouch! Tough audience.
Better slow and tedius I guess than Impossible!
My thought question: Have you ever been told that your query runs too fast?
My advice:
INDEXing a poor-performing query is like putting sugar on cat food. Yeah, it probably tastes better but are you sure you want to eat it?
The path of least resistance can be a slippery slope. Take care that fixing your fixes of fixes doesn't snowball and end up costing you more than fixing the root cause would have in the first place.
Need to UNPIVOT? Why not CROSS APPLY VALUES instead?[/url]
Since random numbers are too important to be left to chance, let's generate some![/url]
Learn to understand recursive CTEs by example.[/url]
[url url=http://www.sqlservercentral.com/articles/St
August 30, 2012 at 6:23 am
SQLHeap (8/30/2012)
Pretty clever dwain, thanks for your input!
Hey! Almost missed your thanks there! π You're very welcome.
And don't listen to ChrisM@Work - he's just a grumpy old, fuddy duddy. π
My thought question: Have you ever been told that your query runs too fast?
My advice:
INDEXing a poor-performing query is like putting sugar on cat food. Yeah, it probably tastes better but are you sure you want to eat it?
The path of least resistance can be a slippery slope. Take care that fixing your fixes of fixes doesn't snowball and end up costing you more than fixing the root cause would have in the first place.
Need to UNPIVOT? Why not CROSS APPLY VALUES instead?[/url]
Since random numbers are too important to be left to chance, let's generate some![/url]
Learn to understand recursive CTEs by example.[/url]
[url url=http://www.sqlservercentral.com/articles/St
August 30, 2012 at 6:27 am
you could search for words that exist after "FROM" and "JOIN", right? and that should get the tables, regardless of the prefix?
I'm playing wiht a splitting with a delimited split, and joining it against itself to get the tables?
this seems to work:
create table #temp1 (query nvarchar(max))
insert into #temp1
values (' SELECT * FROM dbo.table1')
, (' SELECT col1, col23 FROM dbo.table2 a join dbo.table3 b on a.col1 = b.col1')
insert into #temp1
values (' SELECT * FROM table1')
, (' SELECT col1, col23 FROM table2 a join table3 b on a.col1 = b.col1')
SELECT * FROM #temp1
CROSS APPLY dbo.DelimitedSplit8K(query,' ') T1
CROSS APPLY dbo.DelimitedSplit8K(query,' ') T2
WHERE T1.ItemNumber + 1 = T2.ItemNumber
AND T1.Item IN('JOIN','FROM')
Lowell
August 30, 2012 at 6:27 am
dwain.c (8/29/2012)
Well, one thing that you could do if you were so inclined is to add the schema prefix (e.g., dbo.) to each referenced table in each query.This is supposed to make a query a little more efficient (what I've read but never measured), but the important thing is that you could then use the schema prefix to parse out the table names.
As an example:
create table #temp1 (query nvarchar(max))
insert into #temp1
values (' SELECT * FROM dbo.table1')
, (' SELECT col1, col23 FROM dbo.table2 a join dbo.table3 b on a.col1 = b.col1')
;WITH rCTE (tablename, query, n) AS (
SELECT SUBSTRING(str1, 1, CHARINDEX(' ', str1 + ' '))
,SUBSTRING(str1, CHARINDEX(' ', str1 + ' '), 1+LEN(str1))
,n=ROW_NUMBER() OVER (ORDER BY (SELECT NULL))
FROM #temp1
CROSS APPLY (SELECT SUBSTRING(query, CHARINDEX('dbo.', query), LEN(query))) x (str1)
UNION ALL
SELECT SUBSTRING(str1, 1, CHARINDEX(' ', str1 + ' '))
,SUBSTRING(str1, CHARINDEX(' ', str1 + ' '), 1+LEN(str1)), n
FROM rCTE
CROSS APPLY (SELECT SUBSTRING(query, CHARINDEX('dbo.', query), LEN(query))) x (str1)
WHERE query <> '' AND SUBSTRING(str1, 1, CHARINDEX(' ', str1 + ' ')) <> '')
SELECT DISTINCT tablename
FROM rCTE
DROP TABLE #temp1
Should even be reasonably swift assuming your queries don't have 100 tables in each. π
Nice solution!!!! π
August 30, 2012 at 6:32 am
i get very few false positives when i go after my procedure and function definitions using that technique:
SELECT definition,T1.*,T2.* from sys.sql_modules
CROSS APPLY dbo.DelimitedSplit8K(definition,' ') T1
CROSS APPLY dbo.DelimitedSplit8K(definition,' ') T2
WHERE T1.ItemNumber + 1 = T2.ItemNumber
AND T1.Item IN('JOIN','FROM')
Lowell
August 30, 2012 at 6:43 am
dwain.c (8/30/2012)
SQLHeap (8/30/2012)
Pretty clever dwain, thanks for your input!Hey! Almost missed your thanks there! π You're very welcome.
And don't listen to ChrisM@Work - he's just a grumpy old, fuddy duddy. π
Haha! Even more so today, the weather here's horrible π
For fast, accurate and documented assistance in answering your questions, please read this article.
Understanding and using APPLY, (I) and (II) Paul White
Hidden RBAR: Triangular Joins / The "Numbers" or "Tally" Table: What it is and how it replaces a loop Jeff Moden
August 30, 2012 at 6:52 am
Very nice job Lowell, thanks!
There is an exception to every rule, except this one...
August 30, 2012 at 6:54 am
Lowell (8/30/2012)
you could search for words that exist after "FROM" and "JOIN", right? ...
What about: INSERT, INTO, DELETE, TABLE (in possible truncate, create, alter or drop table statements).
Viewing 15 posts - 1 through 15 (of 47 total)
You must be logged in to reply to this topic. Login to reply