Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase

Dynamic query providing wrong output Expand / Collapse
Author
Message
Posted Wednesday, April 24, 2013 8:52 AM
SSC-Enthusiastic

SSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-Enthusiastic

Group: General Forum Members
Last Login: Yesterday @ 12:38 PM
Points: 114, Visits: 527
I have a table data_profile_stats which contains all possible information about all the tables and columns in the DB. I have a cursor running over data_profile_stats which goes line by line, picks up a table name, column name and creates a dynamic query. This query is used to count number of blank values in that column. For some reason, instead of an INTEGER number, I am getting '*' as output which is wrong. Here is the query:

SET @QUERY='SELECT @BLANK_COUNT= COUNT(*) FROM ['+@DB_NAME+'].['+@SCHEMA_NAME+'].['+@TABLE_NAME + '] WHERE ['+@DB_NAME+'].['+@SCHEMA_NAME+'].['+@TABLE_NAME+'].['+@COLUMN_NAME + ']='+''''+''''

EXEC SP_EXECUTESQL @QUERY, N'@BLANK_COUNT INT OUTPUT', @BLANK_COUNT=@BLANK_COUNT OUTPUT

SET @QUERY='UPDATE [dbo].[Data_Profile_Stats] SET BLANK_COUNT='+''''+CAST(@BLANK_COUNT AS VARCHAR(5))+''''+' WHERE [DB_NAME]='+''''+@DB_NAME+''''+' AND SCHEMA_NAME='+''''+@SCHEMA_NAME+''''+' AND TABLE_NAME='+''''+@TABLE_NAME+''''+' AND COLUMN_NAME='+''''+@COLUMN_NAME+''''

exec sp_executesql @QUERY

Example of queries are:

SELECT @BLANK_COUNT= COUNT(*) FROM [TEST].[dbo].[TBL_1] WHERE [TEST].[dbo].[TBL_1].[TCode]=''

UPDATE [dbo].[Data_Profile_Stats] [red]SET BLANK_COUNT='*'[/red] WHERE [DB_NAME]='TEST' AND SCHEMA_NAME='dbo' AND TABLE_NAME='TBL_1' AND COLUMN_NAME='TCode'

As you can see, Blank_Count is getting set to *..can someone please help me out here
Post #1446039
Posted Wednesday, April 24, 2013 9:45 AM


SSC-Insane

SSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-Insane

Group: General Forum Members
Last Login: Today @ 2:45 PM
Points: 20,685, Visits: 32,289
Can you post your code that actually builds and runs these queries? Also, you may not need two dynamic queries, one to get the count and a second to do the update but it is a bit difficult to figure out, at least for me, from the code you have posted.



Lynn Pettis

For better assistance in answering your questions, click here
For tips to get better help with Performance Problems, click here
For Running Totals and its variations, click here or when working with partitioned tables
For more about Tally Tables, click here
For more about Cross Tabs and Pivots, click here and here
Managing Transaction Logs

SQL Musings from the Desert Fountain Valley SQL (My Mirror Blog)
Post #1446078
Posted Wednesday, April 24, 2013 10:15 AM
SSC-Enthusiastic

SSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-Enthusiastic

Group: General Forum Members
Last Login: Yesterday @ 12:38 PM
Points: 114, Visits: 527
I solved it with friend's help..instead of CAST(@BLANK_COUNT AS VARCHAR(5)) it should be CAST(@BLANK_COUNT AS VARCHAR(10))
Post #1446104
Posted Wednesday, April 24, 2013 11:42 AM


SSC-Insane

SSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-Insane

Group: General Forum Members
Last Login: Today @ 2:45 PM
Points: 20,685, Visits: 32,289
A different take on what you are doing, wouldn't hurt to give it a try:


/* Provide test data for building script */
declare @DB_NAME nvarchar(128),
@SCHEMA_NAME nvarchar(128),
@TABLE_NAME nvarchar(128),
@COLUMN_NAME nvarchar(128);

select
@DB_NAME = 'TEST',
@SCHEMA_NAME = 'dbo',
@TABLE_NAME = 'TBL_1',
@COLUMN_NAME = 'TCode';

/****************************************/

declare @SQLCmd nvarchar(max),
@SQLParm nvarchar(max);

set @SQLCmd = N'
WITH BlankCount as (
SELECT
BLANK_COUNT = COUNT(*)
FROM
[' + @DB_NAME + N'].[' + @SCHEMA_NAME + N'].[' + @TABLE_NAME + N'] tc
WHERE
tc.[' + @COLUMN_NAME + N'] = ''''
)
UPDATE [dbo].[Data_Profile_Stats] SET
BLANK_COUNT = (select BLANK_COUNT from BlankCount)
WHERE
[DB_NAME] = @DBNAME AND
SCHEMA_NAME = @SCHEMANAME AND
TABLE_NAME = @TABLENAME AND
COLUMN_NAME = @COLUMNNAME;'

set @SQLParm = N'@DBNAME nvarchar(128), @SCHEMANAME nvarchar(128), @TABLENAME nvarchar(128), @COLUMNNAME nvarchar(128)';

print @SQLCmd;

exec sp_executesql @SQLCmd, @SQLParm, @DBNAME = @DB_NAME, @SCHEMANAME = @SCHEMA_NAME, @TABLENAME = @TABLE_NAME, @COLUMNNAME = @COLUMN_NAME;





Lynn Pettis

For better assistance in answering your questions, click here
For tips to get better help with Performance Problems, click here
For Running Totals and its variations, click here or when working with partitioned tables
For more about Tally Tables, click here
For more about Cross Tabs and Pivots, click here and here
Managing Transaction Logs

SQL Musings from the Desert Fountain Valley SQL (My Mirror Blog)
Post #1446144
Posted Wednesday, April 24, 2013 1:11 PM
SSC-Enthusiastic

SSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-Enthusiastic

Group: General Forum Members
Last Login: Yesterday @ 12:38 PM
Points: 114, Visits: 527
Works great..Thanks mate
Post #1446195
Posted Wednesday, April 24, 2013 1:16 PM


SSC-Insane

SSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-Insane

Group: General Forum Members
Last Login: Today @ 2:45 PM
Points: 20,685, Visits: 32,289
Glad to hear it. I think it makes the dynamic code easier to read. You don't have to count all those little single quotes as much.



Lynn Pettis

For better assistance in answering your questions, click here
For tips to get better help with Performance Problems, click here
For Running Totals and its variations, click here or when working with partitioned tables
For more about Tally Tables, click here
For more about Cross Tabs and Pivots, click here and here
Managing Transaction Logs

SQL Musings from the Desert Fountain Valley SQL (My Mirror Blog)
Post #1446200
« Prev Topic | Next Topic »

Add to briefcase

Permissions Expand / Collapse