May 26, 2016 at 5:20 am
1. Dynamic query
declare @dbname varchar(50),@objname varchar(20),@sql varchar(100)
set @dbname='XYZ'
Set @objname='TMP'
Set @sql=N'(Select * from '+@dbname+'.sys.objects where name = '+@objname+')'
EXEC @sql
2. Actual query
select * from XYZ.sys.objects where name='Tmp'
When I am executing query 2nd query I am getting results. But when I am trying with first way I ma getting error as :
Msg 911, Level 16, State 4, Line 5
Database '(Select * from XYZ' does not exist. Make sure that the name is entered correctly.
Can anyone will be able to help
Sagar Sonawane
** Every DBA has his day!!:cool:
May 26, 2016 at 5:28 am
declare @dbname varchar(50),@objname varchar(20),@sql varchar(1000)
set @dbname='XYZ'
Set @objname='TMP'
Set @sql=N'Select * from '+@dbname+'.sys.objects where name = '''+@objname+''''
Execute (@sql)
May 26, 2016 at 6:36 am
I MUCH prefer to do my dynamic SQL this way. Now I don't have to worry about if it is 1, 2, 3, N stupid single quotes to make the string correct!! 🙂
SET QUOTED_IDENTIFIER OFF
GO
declare @dbname varchar(50),@objname varchar(20),@sql varchar(1000)
set @dbname='XYZ'
Set @objname='TMP'
Set @sql="Select * from "+@dbname+".sys.objects where name = '"+@objname+"'"
Execute (@sql)
Best,
Kevin G. Boles
SQL Server Consultant
SQL MVP 2007-2012
TheSQLGuru on googles mail service
June 2, 2016 at 7:02 am
I prefer to use QUOTENAME which will escape quotes and brackets correctly, as well as handle weird names.
DECLARE
@dbname sysname,
@objname sysname,
@sql nvarchar(1000);
SET @dbname = 'XYZ';
SET @objname = 'TMP';
SET @sql = 'Select * from ' + QUOTENAME(@dbname) + '.sys.objects where name = ' + QUOTENAME( @objname, '''');
EXECUTE (@sql);
June 2, 2016 at 8:36 am
Luis Cazares (6/2/2016)
I prefer to use QUOTENAME which will escape quotes and brackets correctly, as well as handle weird names.
DECLARE
@dbname sysname,
@objname sysname,
@sql nvarchar(1000);
SET @dbname = 'XYZ';
SET @objname = 'TMP';
SET @sql = 'Select * from ' + QUOTENAME(@dbname) + '.sys.objects where name = ' + QUOTENAME( @objname, '''');
EXECUTE (@sql);
That doesn't help in the case of filter values though. :ermm:
Best,
Kevin G. Boles
SQL Server Consultant
SQL MVP 2007-2012
TheSQLGuru on googles mail service
June 2, 2016 at 8:39 am
TheSQLGuru (6/2/2016)
Luis Cazares (6/2/2016)
I prefer to use QUOTENAME which will escape quotes and brackets correctly, as well as handle weird names.
DECLARE
@dbname sysname,
@objname sysname,
@sql nvarchar(1000);
SET @dbname = 'XYZ';
SET @objname = 'TMP';
SET @sql = 'Select * from ' + QUOTENAME(@dbname) + '.sys.objects where name = ' + QUOTENAME( @objname, '''');
EXECUTE (@sql);
That doesn't help in the case of filter values though. :ermm:
No, that's why we use parametrized queries for filter values using sp_executesql.
June 2, 2016 at 9:02 am
Luis Cazares (6/2/2016)
TheSQLGuru (6/2/2016)
Luis Cazares (6/2/2016)
I prefer to use QUOTENAME which will escape quotes and brackets correctly, as well as handle weird names.
DECLARE
@dbname sysname,
@objname sysname,
@sql nvarchar(1000);
SET @dbname = 'XYZ';
SET @objname = 'TMP';
SET @sql = 'Select * from ' + QUOTENAME(@dbname) + '.sys.objects where name = ' + QUOTENAME( @objname, '''');
EXECUTE (@sql);
That doesn't help in the case of filter values though. :ermm:
No, that's why we use parametrized queries for filter values using sp_executesql.
Sadly my experience has been that clients have a tough time or don't know proper use of sp_executesql and default to the easier direct execution. :crying:
Best,
Kevin G. Boles
SQL Server Consultant
SQL MVP 2007-2012
TheSQLGuru on googles mail service
June 2, 2016 at 9:17 am
TheSQLGuru (6/2/2016)
Luis Cazares (6/2/2016)
No, that's why we use parametrized queries for filter values using sp_executesql.Sadly my experience has been that clients have a tough time or don't know proper use of sp_executesql and default to the easier direct execution. :crying:
I'm sure they'll find it easier to use once you show them some examples on how SQL Injection can hurt their databases.
Viewing 9 posts - 1 through 8 (of 8 total)
You must be logged in to reply to this topic. Login to reply