October 1, 2012 at 4:40 pm
Hi,
In code below, how can I evaluate a declared variable if no valid data is returned from attempt to select a field into a variable? What am I missing? I've seen examples that are doing this as defined below.(yes, the temp table does have data; knowing that data I've been able to select into the variable just fine. . . but when nothing is returned and assigned to the variable. . .why isn't something like NULL placed in the variable? Or, the variable being varchar, wouldn't it be a len() = 0? Show me the way, please.
Declare @MyNumberReturn as varchar(6)
Declare @OrderNum as varchar(6)
SET @OrderNum = '123456'
SET @MyNumberReturn = '000000'
SELECT @MyNumberReturn = (SELECT OrderNo FROM ##tmpSlsTaxOrdsDtl WHERE OrderNo = @OrderNum )
--works fine if a result is returned to @MyNumRtrn--Can't eval variable if no result is returned.
print len(@MyNumberReturn ) --get nothing -- how about zero as len()?
if (@MyNumberReturn IS NULL) --get nothing
PRINT 'Invoice #: ' + @MyNumberReturn
else print @MyNumberReturn --if result returned to @MyNumberReturn, the data is printed.
print '@@ERROR: ' + Convert(nvarchar(30), @@ERROR) --always = 0.
October 1, 2012 at 4:49 pm
That is because you are SETting the value for your variable before the SELECT statment..
SET @MyNumberReturn = '000000'
You code should be
IF @MyNumberReturn = '000000' OR @MyNumberReturn IS NULL
THEN
PRINT 'NOTHING'
ELSE
<DO SOMETHING>
October 1, 2012 at 10:10 pm
Yes! That works as desired. Thank You!
Are there other ways though, for evaluating it?
--something like:
IF isnull(@OrderNumRtrn, 0) = 0 OR @OrderNumRtrn = '000000'
PRINT 'Do Something'
ELSE
PRINT 'Do Nothing'
I did not know I couldn't SET @Variable before trying to SELECT into it, and have it be a factor. I guess I'm thinking that SELECTing into the variable would overwrite the initial string value. And, if there is nothing returned by the query,the SELECT would set @Variable to NULL.
October 2, 2012 at 2:33 am
jmccoy-1028380 (10/1/2012)
Yes! That works as desired. Thank You!Are there other ways though, for evaluating it?
--something like:
IF isnull(@OrderNumRtrn, 0) = 0 OR @OrderNumRtrn = '000000'
PRINT 'Do Something'
ELSE
PRINT 'Do Nothing'
I did not know I couldn't SET @Variable before trying to SELECT into it, and have it be a factor. I guess I'm thinking that SELECTing into the variable would overwrite the initial string value. And, if there is nothing returned by the query,the SELECT would set @Variable to NULL.
The ISNULL function used like this offers no gains - it's a cast and a comparison instead of just a comparison.
SELECTing into a variable will overwrite the initial value. If a single row (and column) is returned, then the variable will be assigned the value. If more than one row is returned, then the variable will be assigned one of the values, probably the first in the result set - depending on how the valus is assigned:
DECLARE @name varchar(20)
SELECT @name = name FROM sys.columns WHERE name = 'xptl'
SELECT @name
-- returns NULL
SET @name = 'xxxx'
SELECT @name = (SELECT name FROM sys.columns WHERE name = 'xptl')
SELECT @name
-- returns NULL
SET @name = 'xxxx'
SELECT @name = name FROM sys.columns WHERE name like 'a%'
SELECT @name
-- returns 'auid', last row value from 13 rows
SET @name = 'xxxx'
SELECT @name = (SELECT name FROM sys.columns WHERE name like 'a%')
SELECT @name
-- error: Subquery returned more than 1 value.
-- This is not permitted when the subquery follows =, !=, <, <= , >, >=
-- or when the subquery is used as an expression.
For fast, accurate and documented assistance in answering your questions, please read this article.
Understanding and using APPLY, (I) and (II) Paul White
Hidden RBAR: Triangular Joins / The "Numbers" or "Tally" Table: What it is and how it replaces a loop Jeff Moden
October 2, 2012 at 2:39 am
You could try setting @MyNumberReturn to null instead of '000000'.
Then you'd only need to check if it was null:
if object_id('tempdb..##tmpSlsTaxOrdsDtl') is not null
drop table ##tmpSlsTaxOrdsDtl;
create table ##tmpSlsTaxOrdsDtl
(
OrderNo varchar(6)
);
--insert ##tmpSlsTaxOrdsDtl values ( '123456' );
Declare @MyNumberReturn as varchar(6);
Declare @OrderNum as varchar(6);
SET @OrderNum = '123456';
SET @MyNumberReturn = NULL;
SELECT @MyNumberReturn = (SELECT OrderNo FROM ##tmpSlsTaxOrdsDtl WHERE OrderNo = @OrderNum );
if (@MyNumberReturn IS NULL)
PRINT '@MyNumberReturn is null'
else print @MyNumberReturn; --if result returned to @MyNumberReturn, the data is printed.
select @MyNumberReturn;
Also note: If you concatenate a string with null you get null, so this:
if (@MyNumberReturn IS NULL) --get nothing
PRINT 'Invoice #: ' + @MyNumberReturn
will not show anything when @MyNumberReturn is null.
BTW You need to set the variable to null before running the query, because if no rows are returned the variable IS NOT UPDATED!
October 2, 2012 at 4:35 am
ColdCoffee (10/1/2012)
You code should be
IF @MyNumberReturn = '000000' OR @MyNumberReturn IS NULL
THEN
PRINT 'NOTHING'
ELSE
<DO SOMETHING>
Equivalent should be:
IF ISNULL(@MyNumberReturn, '000000') = '000000' THEN
PRINT 'NOTHING'
ELSE
<DO SOMETHING>
My thought question: Have you ever been told that your query runs too fast?
My advice:
INDEXing a poor-performing query is like putting sugar on cat food. Yeah, it probably tastes better but are you sure you want to eat it?
The path of least resistance can be a slippery slope. Take care that fixing your fixes of fixes doesn't snowball and end up costing you more than fixing the root cause would have in the first place.
Need to UNPIVOT? Why not CROSS APPLY VALUES instead?[/url]
Since random numbers are too important to be left to chance, let's generate some![/url]
Learn to understand recursive CTEs by example.[/url]
[url url=http://www.sqlservercentral.com/articles/St
October 2, 2012 at 7:10 am
Chris,
Thanks. Those are very helpful pointers on what works and does not work. And thanks for the reference to Moden's article. I should've included some DDL for the table referenced.. . . and the inserts for a few records. Thinking about it, if that is all provided, then it is feasible to attempt to assist someone. Otherwise it's a real challenge.
Jim
October 2, 2012 at 7:15 am
Just a personal preference but I prefer laurie's solution. Never liked seeing ISNULL used in that fashion.
October 2, 2012 at 9:50 am
CELKO (10/2/2012)
...
Why would anyone create a local variable (like we did in 1950's assembly languages) to hold the results of an expression. We just use the expression itself in declarative languages.
...
YOU, may be do, but WE don't! Most of modern languages do have concept of "variable" and T-SQL is one of them.
Many T-SQL experts don't ALWAYS use expression itself in a declarative languages such as T-SQL which allows to hold intermediate result in a variable. For example (as per given OP post) if you want to get one single record ID and then reuse it multiple times within process, the use of variable is more than reasonable!
CELKO (10/2/2012)
...
Actually, we use the ANSI/ISO Standard SET for assignment and not the old 1970's Sybase SELECT. The SELECT assignment has cardinality problems. Now look at where you did the assignment to the fake assembly language register you did with a local variable.
YOU, may be ALWAYS do, but WE don't! Before SQL2008 allowed to initialise variables in time of declaration, many T-SQL experts very often used single SELECT statements to initialise multiple variables at once. Even now, it is used widely for initialising variables from relevant table/query.
Actually, you kind of contradict yourself: if you would never create a local variable (like you did in 1950's assembly languages) to hold the results of an expression why ANSI have a SET?
But what is important to understand is how SELECT behaves when it's used for setting variables.
Let see this:
DECLARE @name VARCHAR(255) = 'xxxx'
SELECT @name = (SELECT name FROM sys.columns WHERE name like 'a%')
SELECT @name
What would be possible results of this query? It depends!
1. If no records found in sys.columns the value of @name will be reset to NULL
2. If single record found in sys.columns the value of @name will set the [name] returned by select
3. If multiple records found in sys.columns you will get run-time error "Subquery returned more than 1 value..."
I'do, personally, really hate this behaviour, so I never using this sort of logic. Instead I am using SELECT per following:
DECLARE @name VARCHAR(255) = 'xxxx'
SELECT @name = name FROM sys.columns WHERE name like 'a%'
SELECT @name
In this case:
1. If no records found in sys.columns the value of @name is not reset to NULL, so initialise value stays
2. If single record found in sys.columns the value of @name will set the [name] returned by select
3. If multiple records found in sys.columns you will NOT cause get run-time error and will be set to one of values returned by SELECT (you cannot guarantee which one)
Here is #3 requires a special attention.
if your SELECT may potentially return multiple record (as per given example), then such initialising query is most likely is not appropriate at all! However, there are some cases where it's really doesn't meter, so it can be used safely without causing run-time errors.
October 2, 2012 at 11:36 am
3. If multiple records found in sys.columns you will NOT cause get run-time error and will be set to one of values returned by SELECT (you cannot guarantee which one)
Actually you do know which one. It is the LAST value selected. With no order by on the query you don't know, but if you add an order by you know exactly which one it will return.
_______________________________________________________________
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 Modens splitter http://www.sqlservercentral.com/articles/Tally+Table/72993/.
Cross Tabs and Pivots, Part 1 – Converting Rows to Columns - http://www.sqlservercentral.com/articles/T-SQL/63681/
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs - http://www.sqlservercentral.com/articles/Crosstab/65048/
Understanding and Using APPLY (Part 1) - http://www.sqlservercentral.com/articles/APPLY/69953/
Understanding and Using APPLY (Part 2) - http://www.sqlservercentral.com/articles/APPLY/69954/
Viewing 10 posts - 1 through 9 (of 9 total)
You must be logged in to reply to this topic. Login to reply