Author |
Topic |
anderskd
Starting Member
25 Posts |
Posted - 2007-02-09 : 13:41:14
|
Hello,I'm a little stumped on a solution for this problem. I am querying essentially the same tables from different databases. There is one field that I need to pull, that only exists on some of the databases. Can anyone think of an if statement or error handler that can determine which query to run based on if the field exists or not.This is going to be ran through about 50 databases, so I need the SP to decide which statement to run.Example --if field ZIP exists in the table SELECT NAME, ZIP FROM CUSTOMER--if not exists SELECT NAME, 'NA' FROM CUSTOMER--END IFThanks for any help that may be provided! |
|
X002548
Not Just a Number
15586 Posts |
|
anderskd
Starting Member
25 Posts |
Posted - 2007-02-09 : 14:13:05
|
Thanks for pointing me in the right direction on this. For some reason I've never referecned the INFORMATION_SCHEMA. It is super helpful.Here's what the code will look like:DECLARE @PAYEXIST INTSELECT @PAYEXIST = COUNT(*) FROM MYDATABASE.INFORMATION_SCHEMA.COLUMNSWHERE COLUMN_NAME = 'PAYINVOICEID'PRINT @PAYEXISTIF @PAYEXIST > 0 SELECT 'ITS THERE' FROM INVC_COUNTELSE SELECT 'NOT THERE' FROM INVC_COUNT |
 |
|
Michael Valentine Jones
Yak DBA Kernel (pronounced Colonel)
7020 Posts |
Posted - 2007-02-09 : 14:22:14
|
quote: Originally posted by anderskd Thanks for pointing me in the right direction on this. For some reason I've never referecned the INFORMATION_SCHEMA. It is super helpful.Here's what the code will look like:DECLARE @PAYEXIST INTSELECT @PAYEXIST = COUNT(*) FROM MYDATABASE.INFORMATION_SCHEMA.COLUMNSWHERE COLUMN_NAME = 'PAYINVOICEID'PRINT @PAYEXISTIF @PAYEXIST > 0 SELECT 'ITS THERE' FROM INVC_COUNTELSE SELECT 'NOT THERE' FROM INVC_COUNT
You should modify that code to make sure it is in the table you are interested in. You need to check the TABLE_SCHEMA and the TABLE_NAME in your query.CODO ERGO SUM |
 |
|
anderskd
Starting Member
25 Posts |
Posted - 2007-02-09 : 14:51:58
|
Good call Michael. I almost forgot to add that in!Thanks |
 |
|
Michael Valentine Jones
Yak DBA Kernel (pronounced Colonel)
7020 Posts |
Posted - 2007-02-09 : 15:01:02
|
Another way to do it:if col_length('dbo.INVC_COUNT','PAYINVOICEID') > 0 begin SELECT 'ITS THERE' FROM INVC_COUNT endELSE begin SELECT 'NOT THERE' FROM INVC_COUNT end CODO ERGO SUM |
 |
|
anderskd
Starting Member
25 Posts |
Posted - 2007-02-09 : 17:16:31
|
New dilima on this -Does anyone know a way to reference the INFORMATION_SCHEMA view across a linked server?I can reference different databases on the same server like this:SELECT @PAYEXIST = COUNT(*) FROM DB1.INFORMATION_SCHEMA.COLUMNSSELECT @PAYEXIST = COUNT(*) FROM DB2.INFORMATION_SCHEMA.COLUMNS--but this doesn't workSELECT @PAYEXIST = COUNT(*) FROM SQLSERV1.DB1.INFORMATION_SCHEMA.COLUMNSSELECT @PAYEXIST = COUNT(*) FROM SQLSERV2.DB3.INFORMATION_SCHEMA.COLUMNSMaybe I just have the wrong syntax. I'm stumped. |
 |
|
Michael Valentine Jones
Yak DBA Kernel (pronounced Colonel)
7020 Posts |
Posted - 2007-02-09 : 18:30:59
|
Try this:select count(*)from openquery(SQLSERV1,'Select * from DB1.INFORMATION_SCHEMA.COLUMNS) CODO ERGO SUM |
 |
|
anderskd
Starting Member
25 Posts |
Posted - 2007-02-09 : 18:49:07
|
The problem is that I wanted to pass the database and SS name in as variables. The Servername I can handle by a CASE statement (becuase there are only two of them). But when I dynamically put together the select statement together as a string and pass that into the openquery I get errors.It's allright if this doesn't get resolved. I ended up just making two stored procedures. One for DBs that have the field and one for the ones that don't From there it's pretty easy to create exec statements from select statements to decide which of the SPs to run.Thanks for all the help Michael. I've learned a lot from your assistance today!Kelly |
 |
|
|