June 6, 2022 at 10:27 pm
Hello!
I'm writing a query. As per the logic in my SELECT statement there should be a column from a table that might exist. If it does not I should select Null instead
Smth. like the following non compiling code
DECLARE @NoTable bit
SET @NoTable = 1
SELECT
e.SN as ESN,
CASE WHEN @NoTable = 'True' Null
CASE WHEN @NoTable = 'False' NE.SN
END as NESN
FROM tblExist E, tblDoesntExist NE
The problem with this approach is that if [tblDoesntExist] is not there, the script can not be complied
Would someone please suggest a way to solve this
June 6, 2022 at 10:47 pm
Does the table actually exist and you're just checking to see if the column exists or will the table actually be missing?
In either case, I'm pretty sure that you're going to need two separate queries or Dynamic SQL.
--Jeff Moden
Change is inevitable... Change for the better is not.
June 6, 2022 at 11:01 pm
Thank you Jeff, for your follow-up!
The entire table might exist or not. The reason for that—versions of the particular app, so the query must be just one but run in both scenarios.
Would you please elaborate on the dynamic SQL approach?
June 7, 2022 at 6:25 am
Thank you Jeff, for your follow-up!
The entire table might exist or not. The reason for that—versions of the particular app, so the query must be just one but run in both scenarios.
Would you please elaborate on the dynamic SQL approach?
The dynamic SQL won't be examined at compile or run time so a missing table won't cause a failure. Neither will a missing column.
Basically, you can write some code to check sys.columns to see if the column exists. Even if the table does exist, it sound like you still want it to drive around that without failing. So you simply build the query you need as dynamic SQL based on whether the column is available or not. Another way is to have the two queries in separate stored procedures and decide which one to call based on that same column existence check.
--Jeff Moden
Change is inevitable... Change for the better is not.
June 7, 2022 at 8:40 am
This was removed by the editor as SPAM
June 7, 2022 at 10:36 am
Thank you, Jeff! I'll look into dynamic approach.
June 7, 2022 at 11:08 am
You can do something like this for the dynamic SQL
DECLARE @SQL nvarchar(MAX);
IF OBJECT_ID(N'dbo.tblDoesntExist', N'U') IS NULL
BEGIN
-- TABLE does not exist
SET @SQL = N'
SELECT ESN = E.SN
, NESN = NULL
FROM dbo.tblExist AS E;';
END;
ELSE
BEGIN
-- TABLE does exist
SET @SQL = N'
SELECT ESN = E.SN
, NESN = NE.SN
FROM dbo.tblExist AS E
CROSS JOIN dbo.tblDoesntExist AS NE;';
END;
EXEC sys.sp_executesql @stmt = @SQL;
Viewing 7 posts - 1 through 6 (of 6 total)
You must be logged in to reply to this topic. Login to reply