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 12»»

Give Varibale as column name Expand / Collapse
Author
Message
Posted Friday, November 2, 2012 9:51 AM
SSC-Enthusiastic

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

Group: General Forum Members
Last Login: Tuesday, September 17, 2013 2:07 PM
Points: 171, Visits: 556
Hi ,
I want to give variable as column name.

Example:

DECLARE
@COPYDATE DATETIME
,@COPYDATE_END_OF_CURR_MONTH DATETIME
,@COPYDATE_END_OF_1_MONTH_AGO DATETIME
,@COPYDATE_END_OF_2_MONTH_AGO DATETIME
,@COPYDATE_END_OF_3_MONTH_AGO DATETIME
,@TODAY DATETIME

SET @COPYDATE = '10/31/2012'
SET @COPYDATE_END_OF_CURR_MONTH = DATEADD(DAY,-1,DATEADD(MM, DATEDIFF(M,0,@COPYDATE)+1,0))
SET @COPYDATE_END_OF_1_MONTH_AGO = DATEADD(DAY,-1,DATEADD(MM, DATEDIFF(M,0,@COPYDATE),0))
SET @COPYDATE_END_OF_2_MONTH_AGO = DATEADD(DAY,-1,DATEADD(MM, DATEDIFF(M,0,@COPYDATE)-1,0))
SET @COPYDATE_END_OF_3_MONTH_AGO = DATEADD(DAY,-1,DATEADD(MM, DATEDIFF(M,0,@COPYDATE)-2,0))
SET @TODAY = CONVERT(VARCHAR, GETDATE(), 101)



SELECT
SUM(CASE WHEN MONTH_1 = DATEADD(MM,DATEDIFF(MM,0,@COPYDATE_END_OF_3_MONTH_AGO),0) THEN 1 ELSE 0 END) AS (SELECT @COPYDATE_END_OF_3_MONTH_AGO )
,SUM(CASE WHEN MONTH_1 = DATEADD(MM,DATEDIFF(MM,0,@COPYDATE_END_OF_2_MONTH_AGO),0) THEN 1 ELSE 0 END) AS (SELECT @COPYDATE_END_OF_2_MONTH_AG0 )
,SUM(CASE WHEN MONTH_1 = DATEADD(MM,DATEDIFF(MM,0,@COPYDATE_END_OF_1_MONTH_AGO),0) THEN 1 ELSE 0 END) AS (SELECT @COPYDATE_END_OF_1_MONTH_AGO )
FROM #MAIN_TABLE
GROUP BY MONTH_1


Is it possible ...if not how to get it??

Thanks,
Komal
Post #1380472
Posted Friday, November 2, 2012 10:04 AM


SSChampion

SSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampion

Group: General Forum Members
Last Login: Today @ 2:32 PM
Points: 13,067, Visits: 11,903
That seems like a horrible way to name your columns but in order to do that you will have to use dynamic sql. Make you sure you wrap your column names with [] or it won't work.

_______________________________________________________________

Need help? Help us help you.

Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.

Need to split a string? Try Jeff Moden's splitter.

Cross Tabs and Pivots, Part 1 – Converting Rows to Columns
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs
Understanding and Using APPLY (Part 1)
Understanding and Using APPLY (Part 2)
Post #1380482
Posted Friday, November 2, 2012 10:05 AM
SSCrazy

SSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazy

Group: General Forum Members
Last Login: Friday, July 4, 2014 3:55 AM
Points: 2,836, Visits: 5,062
It's possible with using Dynamic Sql. Here just a small sample, but you should be able to get your one from here:

-- that could be your proc input parameter:
DECLARE @ColumnName NVARCHAR(100)
SET @ColumnName = 'Name'

------------------------
DECLARE @SQL NVARCHAR(4000)

-- let's call it template:
SET @SQL = N'SELECT ~ FROM sys.tables'

-- note use of QUOTENAME to prevent sql injection, also it will good for your columns name as it wrap them into []
SET @SQL = REPLACE(@SQL,'~',QUOTENAME(@ColumnName))

EXEC sp_executesql @SQL



_____________________________________________
"The only true wisdom is in knowing you know nothing"
"O skol'ko nam otkrytiy chudnyh prevnosit microsofta duh!"
(So many miracle inventions provided by MS to us...)

How to post your question to get the best and quick help
Post #1380483
Posted Friday, November 2, 2012 10:12 AM


Hall of Fame

Hall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of Fame

Group: General Forum Members
Last Login: Today @ 3:38 PM
Points: 3,320, Visits: 7,168
Sean Lange (11/2/2012)
That seems like a horrible way to name your columns but in order to do that you will have to use dynamic sql. Make you sure you wrap your column names with [] or it won't work.

As horrible as it seems, I know it can happen.
Once, a developer asked me to use the column names exactly as the user should view them to avoid additional processing and coding at the front end.
This works for reports, not for creating permanent tables.



Luis C.
I am a great believer in luck, and I find the harder I work the more I have of it. Stephen Leacock

Forum Etiquette: How to post data/code on a forum to get the best help
Post #1380489
Posted Friday, November 2, 2012 10:27 AM


SSChampion

SSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampion

Group: General Forum Members
Last Login: Today @ 2:32 PM
Points: 13,067, Visits: 11,903
Luis Cazares (11/2/2012)
Sean Lange (11/2/2012)
That seems like a horrible way to name your columns but in order to do that you will have to use dynamic sql. Make you sure you wrap your column names with [] or it won't work.

As horrible as it seems, I know it can happen.
Once, a developer asked me to use the column names exactly as the user should view them to avoid additional processing and coding at the front end.
This works for reports, not for creating permanent tables.


Yeah I too have that type of requirement and I shudder. Seems like many times they come back and agree with me that the column names are horrible. Of course you still have to know how to tweak that dynamic sql to get those names the first time.


_______________________________________________________________

Need help? Help us help you.

Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.

Need to split a string? Try Jeff Moden's splitter.

Cross Tabs and Pivots, Part 1 – Converting Rows to Columns
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs
Understanding and Using APPLY (Part 1)
Understanding and Using APPLY (Part 2)
Post #1380497
Posted Friday, November 2, 2012 12:33 PM
SSC-Enthusiastic

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

Group: General Forum Members
Last Login: Tuesday, September 17, 2013 2:07 PM
Points: 171, Visits: 556
I did something like this below:

DECLARE @COPYDATE datetime
,@COPYDATE_END_OF_CURR_MONTH varchar(50)
,@COPYDATE_END_OF_1_MONTH_AGO varchar(50)
,@COPYDATE_END_OF_2_MONTH_AGO varchar(50)
,@COPYDATE_END_OF_3_MONTH_AGO varchar(50)
,@TODAY DATETIME

SET @COPYDATE = '10/31/2012'

SET @COPYDATE_END_OF_CURR_MONTH =convert(varchar(50),DATEADD(DAY,-1,DATEADD(MM, DATEDIFF(M,0,@COPYDATE)+1,0)),110)
SET @COPYDATE_END_OF_1_MONTH_AGO = convert(varchar(50),DATEADD(DAY,-1,DATEADD(MM, DATEDIFF(M,0,@COPYDATE),0)),110)
SET @COPYDATE_END_OF_2_MONTH_AGO = convert(varchar(50),DATEADD(DAY,-1,DATEADD(MM, DATEDIFF(M,0,@COPYDATE)-1,0)),110)
SET @COPYDATE_END_OF_3_MONTH_AGO = convert(varchar(50),DATEADD(DAY,-1,DATEADD(MM, DATEDIFF(M,0,@COPYDATE)-2,0)),110)
SET @TODAY = CONVERT(VARCHAR, GETDATE(), 101)



declare @sql varchar(2000)
set @sql = N'SELECT
SUM(CASE WHEN MONTH_1 = DATEADD(MM,DATEDIFF(MM,0,@COPYDATE_END_OF_3_MONTH_AGO),0) THEN 1 ELSE 0 END) AS ['+ @COPYDATE_END_OF_3_MONTH_AGO +']
,SUM(CASE WHEN MONTH_1 = DATEADD(MM,DATEDIFF(MM,0,@COPYDATE_END_OF_2_MONTH_AGO),0) THEN 1 ELSE 0 END) AS ['+@COPYDATE_END_OF_2_MONTH_AGO+' ]
,SUM(CASE WHEN MONTH_1 = DATEADD(MM,DATEDIFF(MM,0,@COPYDATE_END_OF_1_MONTH_AGO),0) THEN 1 ELSE 0 END) AS ['+@COPYDATE_END_OF_1_MONTH_AGO+' ]
FROM #MAIN_TABLE
GROUP BY MONTH_1'

EXEC sp_executesql @sql


Getting ERROr :
Procedure expects parameter '@statement' of type 'ntext/nchar/nvarchar'.
Post #1380554
Posted Friday, November 2, 2012 12:33 PM


SSCommitted

SSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommitted

Group: General Forum Members
Last Login: Sunday, July 20, 2014 11:55 AM
Points: 1,945, Visits: 2,860
I want to give variable as column name.


NO! Please read just one book on RDBMS before you try writing SQL. A column is an attribute of an entity, shown with a scalar value drawn from a domain that is modeled with a single data type.

Renaming columns is magical thinking. It would be like changing lead into gold. Creating new attributes on the fly is also magical thinking. You wave your wand and the elephant grows wings!

Since SQL is a database language, we prefer to do look ups and not calculations. They can be optimized while temporal math messes up optimization. A useful idiom is a report period calendar that everyone uses so there is no way to get disagreements in the DML. The report period table gives a name to a range of dates that is common to the entire enterprise.

CREATE TABLE Report_Periods
(report_name VARCHAR(30) NOT NULL PRIMARY KEY,
report_start_date DATE NOT NULL,
report_end_date DATE NOT NULL,
CONSTRAINT date_ordering
CHECK (report_start_date <= report_end_date),
etc);

These report periods can overlap or have gaps. I like the MySQL convention of using double zeroes for months and years, That is 'yyyy-mm-00' for a month within a year and 'yyyy-00-00' for the whole year. The advantage is that it will sort with the ISO-8601 data format required by Standard SQL.

You still think in monolithic procedural code where the data and process are welded into a single module. Based on teaching SQL for a few decades is that you will need 2-3 years of hard work before you are able to write usable SQL code. It is like learning a foreign language in a different language family from your native one.




Books in Celko Series for Morgan-Kaufmann Publishing
Analytics and OLAP in SQL
Data and Databases: Concepts in Practice
Data, Measurements and Standards in SQL
SQL for Smarties
SQL Programming Style
SQL Puzzles and Answers
Thinking in Sets
Trees and Hierarchies in SQL
Post #1380555
Posted Saturday, November 3, 2012 11:04 AM


SSC-Dedicated

SSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-Dedicated

Group: General Forum Members
Last Login: Today @ 11:31 AM
Points: 36,714, Visits: 31,164
CELKO (11/2/2012)
I want to give variable as column name.


NO! Please read just one book on RDBMS before you try writing SQL. A column is an attribute of an entity, shown with a scalar value drawn from a domain that is modeled with a single data type.

Renaming columns is magical thinking. It would be like changing lead into gold. Creating new attributes on the fly is also magical thinking. You wave your wand and the elephant grows wings!

Since SQL is a database language, we prefer to do look ups and not calculations. They can be optimized while temporal math messes up optimization. A useful idiom is a report period calendar that everyone uses so there is no way to get disagreements in the DML. The report period table gives a name to a range of dates that is common to the entire enterprise.

CREATE TABLE Report_Periods
(report_name VARCHAR(30) NOT NULL PRIMARY KEY,
report_start_date DATE NOT NULL,
report_end_date DATE NOT NULL,
CONSTRAINT date_ordering
CHECK (report_start_date <= report_end_date),
etc);

These report periods can overlap or have gaps. I like the MySQL convention of using double zeroes for months and years, That is 'yyyy-mm-00' for a month within a year and 'yyyy-00-00' for the whole year. The advantage is that it will sort with the ISO-8601 data format required by Standard SQL.


He's not building a table, Joe. He's trying to build a dynamic cross-tab report.

Based on teaching SQL for a few decades is that you will need 2-3 years of hard work before you are able to write usable SQL code.


Not if you have a good teacher.



--Jeff Moden
"RBAR is pronounced "ree-bar" and is a "Modenism" for "Row-By-Agonizing-Row".

First step towards the paradigm shift of writing Set Based code:
Stop thinking about what you want to do to a row... think, instead, of what you want to do to a column."

(play on words) "Just because you CAN do something in T-SQL, doesn't mean you SHOULDN'T." --22 Aug 2013

Helpful Links:
How to post code problems
How to post performance problems
Post #1380726
Posted Saturday, November 3, 2012 11:06 AM


SSC-Dedicated

SSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-Dedicated

Group: General Forum Members
Last Login: Today @ 11:31 AM
Points: 36,714, Visits: 31,164
komal145 (11/2/2012)
EXEC sp_executesql @sql


Getting ERROr :
Procedure expects parameter '@statement' of type 'ntext/nchar/nvarchar'.


The error says exactly what the problem is here. Change @SQL to be an NVARCHAR variable instead of VARCHAR.


--Jeff Moden
"RBAR is pronounced "ree-bar" and is a "Modenism" for "Row-By-Agonizing-Row".

First step towards the paradigm shift of writing Set Based code:
Stop thinking about what you want to do to a row... think, instead, of what you want to do to a column."

(play on words) "Just because you CAN do something in T-SQL, doesn't mean you SHOULDN'T." --22 Aug 2013

Helpful Links:
How to post code problems
How to post performance problems
Post #1380727
Posted Saturday, November 3, 2012 11:19 AM


SSC-Dedicated

SSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-Dedicated

Group: General Forum Members
Last Login: Today @ 11:31 AM
Points: 36,714, Visits: 31,164
komal145 (11/2/2012)
I did something like this below:

DECLARE @COPYDATE datetime
,@COPYDATE_END_OF_CURR_MONTH varchar(50)
,@COPYDATE_END_OF_1_MONTH_AGO varchar(50)
,@COPYDATE_END_OF_2_MONTH_AGO varchar(50)
,@COPYDATE_END_OF_3_MONTH_AGO varchar(50)
,@TODAY DATETIME

SET @COPYDATE = '10/31/2012'

SET @COPYDATE_END_OF_CURR_MONTH =convert(varchar(50),DATEADD(DAY,-1,DATEADD(MM, DATEDIFF(M,0,@COPYDATE)+1,0)),110)
SET @COPYDATE_END_OF_1_MONTH_AGO = convert(varchar(50),DATEADD(DAY,-1,DATEADD(MM, DATEDIFF(M,0,@COPYDATE),0)),110)
SET @COPYDATE_END_OF_2_MONTH_AGO = convert(varchar(50),DATEADD(DAY,-1,DATEADD(MM, DATEDIFF(M,0,@COPYDATE)-1,0)),110)
SET @COPYDATE_END_OF_3_MONTH_AGO = convert(varchar(50),DATEADD(DAY,-1,DATEADD(MM, DATEDIFF(M,0,@COPYDATE)-2,0)),110)
SET @TODAY = CONVERT(VARCHAR, GETDATE(), 101)



declare @sql varchar(2000)
set @sql = N'SELECT
SUM(CASE WHEN MONTH_1 = DATEADD(MM,DATEDIFF(MM,0,@COPYDATE_END_OF_3_MONTH_AGO),0) THEN 1 ELSE 0 END) AS ['+ @COPYDATE_END_OF_3_MONTH_AGO +']
,SUM(CASE WHEN MONTH_1 = DATEADD(MM,DATEDIFF(MM,0,@COPYDATE_END_OF_2_MONTH_AGO),0) THEN 1 ELSE 0 END) AS ['+@COPYDATE_END_OF_2_MONTH_AGO+' ]
,SUM(CASE WHEN MONTH_1 = DATEADD(MM,DATEDIFF(MM,0,@COPYDATE_END_OF_1_MONTH_AGO),0) THEN 1 ELSE 0 END) AS ['+@COPYDATE_END_OF_1_MONTH_AGO+' ]
FROM #MAIN_TABLE
GROUP BY MONTH_1'

EXEC sp_executesql @sql


Getting ERROr :
Procedure expects parameter '@statement' of type 'ntext/nchar/nvarchar'.


I noticed that all of your date variables are VARCHAR which could cause some computational errors and some "implicit conversion" performance problems. I'd like to recommend that you post the CREATE TABLE statement for your #MAIN_TABLE and post some readily consumable data with it so we can help a little better. Please see the article at the first link in my signature line below for how to do that correctly.


--Jeff Moden
"RBAR is pronounced "ree-bar" and is a "Modenism" for "Row-By-Agonizing-Row".

First step towards the paradigm shift of writing Set Based code:
Stop thinking about what you want to do to a row... think, instead, of what you want to do to a column."

(play on words) "Just because you CAN do something in T-SQL, doesn't mean you SHOULDN'T." --22 Aug 2013

Helpful Links:
How to post code problems
How to post performance problems
Post #1380728
« Prev Topic | Next Topic »

Add to briefcase 12»»

Permissions Expand / Collapse