Showing posts with label select. Show all posts
Showing posts with label select. Show all posts

Saturday, October 31, 2009

Stored procedure in a SELECT statement

Objective: Execute a stored procedure inside a SELECT statement and return the result as a table. I found a blog that shows how to execute a stored procedure inside a SELECT statement and return the result as a table. Although this can also be achieved using a table-valued function, this is much useful capturing result sets returned by system stored procedure like, sp_who. Although there are a number of ways to do this, I found this very simple technique. There are a number of consideration before this can be used including: user-rights, configuration setting and the size of the result set to be returned. Also, try to consider using function first. What I did is take advantage of the OPENROWSET function that allows user to access remote data from a data source. Here's a sample of retrieving the result set as returned by the system stored procedure sp_who:
SELECT a.*
FROM OPENROWSET('SQLNCLI', 'Server=.;Trusted_Connection=yes;',
'set fmtonly off; exec sp_who') AS a
As this is like a regular SELECT statement, data merge (JOIN, UNION), filter condition (WHERE) and sorting (ORDER BY) can be used. The result may also be inserted into a table using the INSERT INTO...SELECT statement or to create a new table by including a INTO new_table> statement on the SELECT statement. The new_table may also be a temporary table. Here's another sample. Although the following code may be implemented in some other ways, it was created to illustrate how the stored procedure be executed inside a SELECT statement and return the result. Here's the stored procedure:
create proc tproc (@dbname as varchar(50))
as
begin
   declare @sql varchar(500)
   set @sql = 'select * from ' + @dbname + '.dbo.sysobjects'
   exec (@sql)
end

exec dbo.tproc 'model'
exec dbo.tproc 'master'
To call in a SELECT statement and return as a table:
SELECT a.*
FROM OPENROWSET('SQLNCLI', 'Server=.;Trusted_Connection=yes;',
 'set fmtonly off; exec workdb.dbo.tproc ''master''') AS a;

SELECT a.*
FROM OPENROWSET('SQLNCLI', 'Server=.;Trusted_Connection=yes;',
 'set fmtonly off; exec workdb.dbo.tproc ''model''') AS a;
As always, comments are welcome ....


~~CK

Wednesday, September 24, 2008

What's the Difference Between SET and SELECT?

Is there really a difference between SET and SELECT when used to assign values to variables, in T-SQL? The misconception is that, there's no difference between them. I've been creating SQL Scripts for some time now and had been using these two statements interchangeably. That is until I got an unnoticed logical error resulting from using one instead of the other. So what are the similarities and differences? Both commands can assign values to a variable. For the most part, their similarities end there. Fundamentally, SET is the ANSI standard way of assigning values to a variable, while SELECT is not. Another visible difference is that SET can assign a value to only one variable, while SELECT can assign value to one or more variable at a time. Consider these variables:
declare @myVar1 int, @myVar2 int
This code should run successfully:
SELECT @myVar1 = 1, @myVar2 = 2
print '@myVar1'
print @myVar1
print ''
print '@myVar2'
print @myVar2
Here are the results:
@myVar1
1
 
@myVar2
2
This code will result to an error:
SET @myVar1 = 11, @myVar2 = 12
print '@myVar1'
print @myVar1
print ''
print '@myVar2'
print @myVar2
Here's the error returned:
Msg 102, Level 15, State 1, Line 11
Incorrect syntax near ','.
(I'll use the PRINT command to display variable content to avoid confusion between the command assigning values to variable and displaying values.) In order for this code to run, assignment of values should be done separately for each variable.
SET @myVar1 = 11
SET @myVar2 = 12
print '@myVar1'
print @myVar1
print ''
print '@myVar2'
print @myVar2
Here's the result:
@myVar1
11

@myVar2
12
Standards, however, is not the only consideration when using these two statements. Here's a sample application of how these commands could tremendously affect SQL Scripts:
declare @rowsaffected int, @errornumber int

select id/0 from sysobjects
set @rowsaffected = @@rowcount
set @errornumber = @@error

print 'rowsaffected'
print @rowsaffected
print ''
print 'errornumber'
print @errornumber
Here are the results:
Msg 8134, Level 16, State 1, Line 4
Divide by zero error encountered.

rowsaffected
0

errornumber
0
The code returned an error (division by zero), but the system variable @@error returned zero (0). This is not due to SET and SELECT per se. The @@error system variable checks if there's an error on the last t-sql statement executed. In this case set @rowsaffected = @@rowcount, is a valid statement, hence it did not return any error number. This could result in unhandled errors. In another application, I want to return the number of rows affected.
declare @rowsaffected int, @errornumber int

select id from sysobjects where id <= 10
set @errornumber = @@error
set @rowsaffected = @@rowcount

print 'rowsaffected'
print @rowsaffected
print ''
print 'errornumber'  
print @errornumber
Here are the results:
id
-----------
4
5
7
8

rowsaffected
1
 
errornumber
0
Notice that the query actually returned four rows, but the @@rowcount system variable reported only one row. The @@rowcount is a system variable that returns the number of rows affected by the previous statement. In this case, set @errornumber = @@error, returns one row. Using SET to assign the values of these system variables, in this case, is not advisable. To capture both values at the same time, use the SELECT statement.
declare @rowsaffected int, @errornumber int

select id from sysobjects where id <= 10
select @errornumber = @@error,@rowsaffected = @@rowcount

print 'rowsaffected'
print @rowsaffected
print ''
print 'errornumber'  
print @errornumber

id
-----------
4
5
7
8

rowsaffected
4
 
errornumber
0

select id/0 from sysobjects where id <= 10
select @errornumber = @@error,@rowsaffected = @@rowcount

print 'rowsaffected'
print @rowsaffected
print ''
print 'errornumber'  
print @errornumber
 
-----------
Msg 8134, Level 16, State 1, Line 4
Divide by zero error encountered.

rowsaffected
0
 
errornumber
8134
In both cases, the @@rowcount and @@error returned the right values. SET and SELECT also varies on the way scalar values are being assigned to variables, specifically if the value is coming from a query. Consider this sample table:
SET NOCOUNT ON
declare @Test table (i int, j varchar(15))
INSERT INTO @Test (i, j) VALUES (1, 'First Row')
INSERT INTO @Test (i, j) VALUES (2, 'Second Row')

select * from @Test

i           j
----------- ----------
1           First Row
2           Second Row
Using the two commands:
declare @myVarUseSET varchar(15), @myVarUseSELECT varchar(15)

SET @myVarUseSET = (select j from @Test where i = 2)
SELECT @myVarUseSELECT = j from @Test where i = 2

print '@myVarUseSET'
print @myVarUseSET
print ''
print '@myVarUseSELECT'
print @myVarUseSELECT
Here are the results:
@myVarUseSET
Second Row

@myVarUseSELECT
Second Row
The values are accurately assigned to both variables. What will happen if the query returned more than one rows.
SET @myVarUseSET = (select j from @Test)
SELECT @myVarUseSELECT = j from @Test

print '@myVarUseSET'
print @myVarUseSET
print ''
print '@myVarUseSELECT'
print @myVarUseSELECT
Here are the results:
Msg 512, Level 16, State 1, Line 10
Subquery returned more than 1 value. 
This is not permitted when the subquery follows =, !=, <, <= , >, >= or 
when the subquery is used as an expression.
@myVarUseSET

@myVarUseSELECT
Second Row
Notice that the SET query failed while the SELECT succeeded. How do SELECT statements choose which value among the rows returned will be stored to the variable? It will be the last row returned. If the query has an ORDER BY clause, it will return the last row as sorted by the ORDER BY clause. What will happen if, instead of multiple values returned, the query did not return any rows? To be able to appreciate more, I initialize the value of the variables and tried to assign a value that's coming from a query that did not return any rows.
select @myVarUseSET = 'initial value',
@myVarUseSELECT = 'initial value'

set @myVarUseSET = (select j from @Test where i = 3)
select @myVarUseSELECT = j from @Test where i = 3

print '@myVarUseSET'
print isnull(@myVarUseSET,'NULL')
print ''
print '@myVarUseSELECT'
print isnull(@myVarUseSELECT,'NULL')
Here are the results:
@myVarUseSET
NULL

@myVarUseSELECT
initial value
The way SET executes is that it will set the value of the variable to NULL. SELECT, on the other hand, will not replace the value of the variable. Notice that the variable @myVarUseSELECT still contains the initialized value of the variable. If not properly handled, this could lead to unnoticed errors that might affect the result of any scripts. Lastly, speed. Dealing with a single variable, there's not much of speed differential between the two commands. SET @variable = value and SELECT @variable = value have almost the same speed with very negligible difference. However, if it's dealing with three or more variables SELECT beats SET by almost 50% for the mere fact that SELECT can assign values to multiple variables at a time. Based on the abovementioned samples and cases, speed should not the only thing that must be considered. Keep in mind how these commands handle the results of the assignment operator.


~~ CK

Friday, September 19, 2008

How do SQL Server Programmers Search for Their Dates?

Being a user of SQL Serever, I dealt with searching and using dates in logical conditions, in one way or another. Initially, it was quite confusing.

Here are a couple of factors.

First, it's because, as of SQL 2005, there are no data types that holds date only, nor time only data. SQL Server stores both the date part and time part using the same data type. The only difference is the precision of these data types.

Second is because you have to use string literals to handle static date data. Users usually miss the time part of the string literal. SQL Server will default the converted time part to zero (00:00:00.000). This could lead to logical conditions to return unexpected results. (For more on all these, read my old notes).

Try and simulate some logical conditions. Consider this sample table:
declare @myTable table(rownum int, DateData datetime)
set nocount on

insert into @mytable values(1,'2005-10-14 01:36:25.440')
insert into @mytable values(2,'2005-10-14 01:36:25.497')
insert into @mytable values(3,'2005-10-14 01:36:25.570')
insert into @mytable values(4,'2005-10-14 01:36:25.627')
insert into @mytable values(5,'2005-10-14 01:36:25.683')
insert into @mytable values(6,'2005-10-14 01:36:25.740')
insert into @mytable values(7,'2005-10-15 00:00:00.000')
insert into @mytable values(8,'2008-07-24 12:52:42.360')
insert into @mytable values(9,'2008-07-25 00:00:00.000')
insert into @mytable values(10,'2008-07-25 12:38:35.060')
insert into @mytable values(11,'2008-07-25 12:38:35.137')
insert into @mytable values(12,'2008-07-26 00:00:00.000')
insert into @mytable values(13,'2008-08-13 00:00:00.000')

select * from @myTable

rownum datedata
----------- -----------------------
1 2005-10-14 01:36:25.440
2 2005-10-14 01:36:25.497
3 2005-10-14 01:36:25.570
4 2005-10-14 01:36:25.627
5 2005-10-14 01:36:25.683
6 2005-10-14 01:36:25.740
7 2005-10-15 00:00:00.000
8 2008-07-24 12:52:42.360
9 2008-07-25 00:00:00.000
10 2008-07-25 12:38:35.060
11 2008-07-25 12:38:35.137
12 2008-07-26 00:00:00.000
13 2008-08-13 00:00:00.000

Now search for specific records using the date data as filter condition :
select *
from @myTable
where DateData = '20080724'


select *
from @myTable
where DateData = '20080813'
Here are the result sets:
rownum      datedata
----------- -----------------------

rownum datedata
----------- -----------------------
13 2008-08-13 00:00:00.000
Now, why did the first query did not return any rows while the second query returned the 13th row? That's in spite of row 8 being the only one with date July 24, 2008 anyway.

A more detail analysis shows that the WHERE clause of the query compares the DateData column to a date-formatted string. In order to compare two values, they must be of the same data type, otherwise, the data type with the lower precedence will be converted to the data type with the higher precedence. In this case, datetime is higher than any other native string data types. The first query is synonymous to:
select * from @myTable
where datedata = cast('20080724' as datetime)


rownum datedata
----------- -----------------------
Since the function converted a date-literal with no time part, it sets the time to zero (00:00:00.000). Resulting to a false condition (2008-07-24 12:53:00 <> 2008-07-24 00:00:00.000).

So how do SQL Server Programmers search for their dates? Here are some options how to retrieve the 8th record.

It's always possible tp convert the date column into string with no time part and compare two strings. Something like:
select * from @myTable
where convert(varchar(20), datedata, 112) = '20080724'

rownum datedata
----------- -----------------------
8 2008-07-24 12:52:42.360
It did. Technically, there's nothing wrong with this code. It returned the desired result. The only problem that it will encounter later is performance. SQL Server will not use index to optimize our query since we use a function in date column for our WHERE clause. This is OK if the query is processing a small table. If it's reading a large volume of data, this will tremendously affect the execution time.

Another option is to grab all records with dates between 20080724 AND 20080725.
select * from @myTable
where datedata BETWEEN '20080724' and '20080725'

rownum datedata
----------- -----------------------
8 2008-07-24 12:52:42.360
9 2008-07-25 00:00:00.000
Now why did it include row 9? It's the way how BETWEEN operator works. BETWEEN is a logical operator that operates inclusive-ly. The above query is similar to:
select * from @myTable
where datedata >= '20080724' and datedata <= '20080725'
The second condition will follow the “explicit conversion of lower precedent data type with no time part” rule, so the 9th row was included to the result set. So, try and include the time part:
select * from @myTable 
where datedata
BETWEEN '20080724 00:00:00.000' and '20080724 23:59:59.999'


rownum datedata
----------- -----------------------
8 2008-07-24 12:52:42.360
9 2008-07-25 00:00:00.000
Why did it still return 2 rows? The conversion, as it is, has nothing to do with this. The second expression ('20080724 23:59:59.999') will be properly converted to a DateTime expression, complete with time part. However, the DateTime precision is 3.333 seconds (For more about DateTime and SmallDatetime rounding and precision, read my old notes) resulting the second part to be rounded to '2008-07-25 00:00:00.000'. To resolve this rounding issue, try to prevent the time part from rounding up by doing:
select * from @myTable
where datedata
BETWEEN '20080724 00:00:00.000' and '20080724 23:59:59.998'


rownum datedata
----------- -----------------------
8 2008-07-24 12:52:42.360
And if it's SmallDateTime, the code should be :
select * from @myTable 
where datedata
BETWEEN '20080724 00:00:00.000' and '20080724 23:59:00'


rownum datedata
----------- -----------------------
8 2008-07-24 12:53:00
Now there are two ways of doing it depending on which data types the query is dealing with. Although, these are all valid codes, it is not recommended to have two versions of codes to handle these two sibling data types. Also, it's necessary to be always conscious of whether it's dealing with a DateTime or a SmallDateTime expression. To be more flexible, it would be better to create something like this:
select * from @myTable 
where datedata >='20080724 ' and datedata < '20080725'

rownum datedata
----------- -----------------------
8 2008-07-24 12:53:00
The above code is clearer and SQL Server can also use index for query optimization. For range of dates, it can easily be extended and modify the condition of the same code:
select * from @myTable 
where datedata >='20080724 ' and datedata < '20080727'

rownum datedata
----------- -----------------------
8 2008-07-24 12:53:00
9 2008-07-25 00:00:00
10 2008-07-25 12:39:00
11 2008-07-25 12:39:00
12 2008-07-26 00:00:00
As a general rule, use a method that can handle both DateTime and SmallDateTime, specially if you the requirement does need to deal with the time part. Also, consider the performance of the query. Placing a date data type column in a function as part of a filter condition will ignore the index and will perform a table scan. Most importantly, if using a function is unavoidable, be aware that most date and time functions are dependent to the user's default language, SET LANGUAGE and SET DATEFORMAT settings.



~~CK

Monday, September 15, 2008

The Basics of Dates

On my old notes, I wrote down some of the similarities and differences between smalldatetime and datetime data types. Now I'll write up some more of the basics that must be considered before using these data types.
Default Values
Both these data types use the base date (January 1, 1900) as their default value. Even if Datetime can handle much earlier dates, it will always default to the base date.
select cast('' as smalldatetime) as 'smalldatetime',
cast('' as datetime) as 'datetime'
Here is the result set:
smalldatetime           datetime
----------------------- -----------------------
1900-01-01 00:00:00     1900-01-01 00:00:00.000
Both function returned the base date as the default date.

Time, however, will always default to zero (00:00:00). The only difference is the fractional seconds that DateTime can handle.
select
cast('12/29/2008' as smalldatetime) as 'smalldatetime',
cast('12/29/2008' as datetime) as 'datetime'

smalldatetime            datetime
----------------------- -----------------------
2008-12-29 00:00:00     2008-12-29 00:00:00.000

Rounding and Precisions

SmallDateTime has a simple way of preserving its one minute precision. All dates with 29.998 seconds and below will be rounded down to the nearest minute, all dates with 29.999 seconds and higher will be rounded up to the next minute.
select '20091229 23:59:29.998' as 'string',
cast('20091229 23:59:29.998' as smalldatetime) as 'smalldatetime'

string                smalldatetime
--------------------- -----------------------
20091229 23:59:29.998 2009-12-29 23:59:00


select '20091229 23:59:29.999' as 'string',
cast('20091229 23:59:29.999' as smalldatetime) as 'smalldatetime'

string                smalldatetime
--------------------- -----------------------
20091229 23:59:29.999 2009-12-30 00:00:00
DateTime has a more complicated rounding off calculation. Dates are rounded to increments of .000, .003 or .007 seconds.
Consider the following examples:
declare @DateData table(stringdate varchar(25))
set nocount on
insert into @DateData values('20091229 23:59:29.990')
insert into @DateData values('20091229 23:59:29.991')
insert into @DateData values('20091229 23:59:29.992')
insert into @DateData values('20091229 23:59:29.993')
insert into @DateData values('20091229 23:59:29.994')
insert into @DateData values('20091229 23:59:29.995')
insert into @DateData values('20091229 23:59:29.996')
insert into @DateData values('20091229 23:59:29.997')
insert into @DateData values('20091229 23:59:29.998')
insert into @DateData values('20091229 23:59:29.999')

select stringdate, cast(stringdate as datetime) converted
from @DateData
Here's the result set:
stringdate                converted
------------------------- -----------------------
20091229 23:59:29.990     2009-12-29 23:59:29.990
20091229 23:59:29.991     2009-12-29 23:59:29.990
20091229 23:59:29.992     2009-12-29 23:59:29.993
20091229 23:59:29.993     2009-12-29 23:59:29.993
20091229 23:59:29.994     2009-12-29 23:59:29.993
20091229 23:59:29.995     2009-12-29 23:59:29.997
20091229 23:59:29.996     2009-12-29 23:59:29.997
20091229 23:59:29.997     2009-12-29 23:59:29.997
20091229 23:59:29.998     2009-12-29 23:59:29.997
20091229 23:59:29.999     2009-12-29 23:59:30.000
Notice that .995 is rounded to .997 even if it's exactly between .003 and .007. This is because seconds are still integers and will still follow the integer rule of rounding off.

Formats

Whenever a date values is used in T-SQL, it’s probably specified in string literal. However, SQL Server might incorrectly interpret these strings as different dates. A date value '08/12/05' could be interpreted in six different ways. These interpretations are usually affected by the SET DATEFORMAT and SET LANGUAGE settings. There are some string literals that are not affected by these settings. Unless you are sure of these settings, try using a setting-independent format.

Here are some of the acceptable date literal formats:

Numeric
Separated
'12/29/2008 14:21:00.000'
DF
LN
Numeric
Unseparated
'20081229 14:21:00.000'
-
-
ANSI-SQL'1998-12-23 14:23:05'
DF
LN
Alphabetic'29 December 1998 14:23:05'
-
LN
ODBC
DateTime
{ts '1998-12-29 14:23:05'}
-
-
ODBC Date{d '1998-12-29'
-
-
ODBC Time{t '14:29:09'}
-
-
ISO 8601'1998-12-29T14:27:09'
-
-
Time'14:29:09' '2:29:09 PM'
-
-

DF - SET DATEFORMAT dependent
LN - SET LANGUAGE dependent

Notice that ANSI-SQL is also a numeric-separated format, but still LANGUAGE and DATEFORMAT dependent. ODBC uses escape sequences to identify date (d), time (t) and timestamp (date+time). SQL Server always treats ODBC date data as DateTime.

Let's see how DATEFORMAT and LANGUAGE settings can affect your literal string. The code below will give an error:
set dateformat dmy
select cast('12/29/2008' as datetime)

Here's the result:

-----------------------
Msg 242, Level 16, State 3, Line 2
The conversion of a char data type to a datetime data type resulted in
an out-of-range datetime value.
This code however, is valid:
set dateformat mdy
select cast('12/29/2008' as datetime)
Here's the result:
-----------------------
2008-12-29 00:00:00.000
Here's how language setting can affect your date literals:
set language British
select datename(month,cast('08/12/05' as datetime))
Here's the result:
Changed language setting to British.

------------------------------
December
And changing the setting :
set language us_english
select datename(month,cast('08/12/05' as datetime))
Can change the result of the same code to:
Changed language setting to us_english.
------------------------------
August

To avoid these errors, try to use those formats that are not dependent to LANGUAGE and DATEFORMAT settings.



~~CK