Database Journal
MS SQL Oracle DB2 Access MySQL PostgreSQL Sybase PHP SQL Etc SQL Scripts & Samples Links Database Forum

» Database Journal Home
» Database Articles
» Database Tutorials
MS SQL
Oracle
DB2
MS Access
MySQL
» RESOURCES
Database Tools
SQL Scripts & Samples
Links
» Database Forum
» Sitemap
Free Newsletters:
DatabaseDaily  
News Via RSS Feed


follow us on Twitter
Database Journal |DBA Support |SQLCourse |SQLCourse2
 

Featured Database Articles

MS SQL

Posted Jul 14, 2004

Bits in SQL Server - Page 2

By Muthusamy Anantha Kumar aka The MAK

By creating a function similar to the one below, you are able to query such binary positions. This function displays all of the user options that are enabled.

Create function dbo.UDF_Displayuseroptions 
	(@number smallint)
returns varchar(3300)
as
begin
declare @binary varchar(3300)
select @binary = 
CASE @number&16384 WHEN 16384 
  THEN 'XACT_ABORT ' +char(13)+char(10) 
  ELSE '' END+
CASE @number&8192 WHEN 8192 
  THEN ' NUMERIC_ROUNDABORT ' 
    +char(13)+char(10) 
  ELSE '' END+
CASE @number&4096 WHEN 4096 
  THEN 'CONCAT_NULL_YIELDS_NULL' 
    +char(13)+char(10) 
  ELSE '' END+
CASE @number&2048 WHEN 2048 
  THEN 'ANSI_NULL_DFLT_OFF' 
    +char(13)+char(10) 
  ELSE '' END+
CASE @number&1024 WHEN 1024 
  THEN 'ANSI_NULL_DFLT_ON' 
    +char(13)+char(10) 
  ELSE '' END+
CASE @number&512 WHEN 512 
  THEN 'NOCOUNT' +char(13)+char(10) 
  ELSE '' END+
CASE @number&256 WHEN 256 
  THEN 'QUOTED_IDENTIFIER' 
    +char(13)+char(10) 
  ELSE '' END+
CASE @number&128 WHEN 128 
  THEN 'ARITHIGNORE' +char(13)+char(10) 
  ELSE '' END+
CASE @number&64 WHEN 64 
  THEN 'ARITHABORT' +char(13)+char(10) 
  ELSE '' END+
CASE @number&32 WHEN 32 
  THEN 'ANSI_NULLS' +char(13)+char(10) 
  ELSE '' END+
CASE @number&16 WHEN 16 
  THEN 'ANSI_PADDING' +char(13)+char(10) 
  ELSE '' END+
CASE @number&8 WHEN 8 
  THEN 'ANSI_WARNINGS' +char(13)+char(10) 
  ELSE '' END+
CASE @number&4 WHEN 4 
  THEN 'CURSOR_CLOSE_ON_COMMIT' +char(13)+char(10) 
  ELSE '' END+
CASE @number&2 WHEN 2 
  THEN 'IMPLICIT_TRANSACTIONS' +char(13)+char(10) 
  ELSE '' END
+CASE @number&1 WHEN 1 
  THEN 'DISABLE_DEF_CNST_CHK' +char(13)+char(10) 
  ELSE '' END
return @binary
end

Query

Select @@options

Results

6008

Query

Select dbo.UDF_Displayuseroptions (@@options)

Results

CONCAT_NULL_YIELDS_NULL
ANSI_NULL_DFLT_ON
NOCOUNT
QUOTED_IDENTIFIER
ARITHABORT
ANSI_NULLS
ANSI

Query

Let's disable the "nocount" option in the user option by executing the below query:

Set nocount off

Query

Let us query the user option now.

Select @@options

Results

5496

Query

Let us query the user options by using the function we created.

Select dbo.UDF_Displayuseroptions (@@options)

Results

CONCAT_NULL_YIELDS_NULL
ANSI_NULL_DFLT_ON
QUOTED_IDENTIFIER
ARITHABORT
ANSI_NULLS
ANSI_PADDING

You can also create a function like the one below to see what options are enabled and disabled.

Create  function dbo.UDF_DisplayAlluseroptions (@number smallint)
returns varchar(3300)
as
begin
declare @binary varchar(3300)
select @binary = 
CASE @number&16384 WHEN 16384 THEN 'XACT_ABORT ON ' +char(13)+char(10) 
	ELSE 'XACT_ABORT OFF ' +char(13)+char(10)  END+
CASE @number&8192 WHEN 8192 THEN ' NUMERIC_ROUNDABORT ON ' +char(13)+char(10) 
	ELSE 'NUMERIC_ROUNDABORT OFF ' +char(13)+char(10)  END+
CASE @number&4096 WHEN 4096 THEN 'CONCAT_NULL_YIELDS_NULL ON ' +char(13)+char(10) 
	ELSE 'CONCAT_NULL_YIELDS_NULL OFF ' +char(13)+char(10)  END+
CASE @number&2048 WHEN 2048 THEN 'ANSI_NULL_DFLT_OFF' +char(13)+char(10) ELSE '' END+
CASE @number&1024 WHEN 1024 THEN 'ANSI_NULL_DFLT_ON' +char(13)+char(10) ELSE '' END+
CASE @number&512 WHEN 512 THEN 'NOCOUNT ON ' +char(13)+char(10) 
	ELSE 'NOCOUNT OFF ' +char(13)+char(10)  END+
CASE @number&256 WHEN 256 THEN 'QUOTED_IDENTIFIER ON ' +char(13)+char(10) 
	ELSE 'QUOTED_IDENTIFIER OFF ' +char(13)+char(10)  END+
CASE @number&128 WHEN 128 THEN 'ARITHIGNORE ON ' +char(13)+char(10) 
	ELSE 'ARITHIGNORE OFF ' +char(13)+char(10)  END+
CASE @number&64 WHEN 64 THEN 'ARITHABORT ON ' +char(13)+char(10) 
	ELSE 'ARITHABORT OFF ' +char(13)+char(10)  END+
CASE @number&32 WHEN 32 THEN 'ANSI_NULLS ON ' +char(13)+char(10) 
	ELSE 'ANSI_NULLS OFF ' +char(13)+char(10)  END+
CASE @number&16 WHEN 16 THEN 'ANSI_PADDING ON ' +char(13)+char(10) 
	ELSE 'ANSI_PADDING OFF ' +char(13)+char(10)  END+
CASE @number&8 WHEN 8 THEN 'ANSI_WARNINGS ON ' +char(13)+char(10) 
	ELSE 'ANSI_WARNINGS OFF ' +char(13)+char(10)  END+
CASE @number&4 WHEN 4 THEN 'CURSOR_CLOSE_ON_COMMIT ON ' +char(13)+char(10) 
	ELSE 'CURSOR_CLOSE_ON_COMMIT OFF ' +char(13)+char(10)  END+
CASE @number&2 WHEN 2 THEN 'IMPLICIT_TRANSACTIONS ON ' +char(13)+char(10) 
	ELSE 'IMPLICIT_TRANSACTIONS OFF '+char(13)+char(10)  END+
CASE @number&1 WHEN 1 THEN 'DISABLE_DEF_CNST_CHK ON ' +char(13)+char(10) 
	ELSE 'DISABLE_DEF_CNST_CHK OFF '+char(13)+char(10)  END
return @binary
end

Query

Select @@options

Results

5496

Query

Select dbo.UDF_DisplayAlluseroptions(@@options)

Results

XACT_ABORT OFF 
NUMERIC_ROUNDABORT OFF 
CONCAT_NULL_YIELDS_NULL ON 
ANSI_NULL_DFLT_ON
NOCOUNT OFF 
QUOTED_IDENTIFIER ON 
ARITHIGNORE OFF 
ARITHABORT ON 
ANSI_NULLS ON 
ANSI_PADDING ON 
ANSI_WARNINGS ON 
CURSOR_CLOSE_ON_COMMIT OFF 
IMPLICIT_TRANSACTIONS OFF 
DISABLE_DEF_CNST_CHK OFF 

Another Example on how SQL Server uses binary positions is the table sysjobschedules in the database MSDB. Whenever we create any schedules, it is imperative to configure a job to run on certain days. Lets take the below example. Create a job schedule x and configure it to run on Sunday, Monday, Wednesday, Thursday and Friday (as shown in figure 1.0).


Figure 1.0

When we query the sysjobschedules table in MSDB database, we get result 59.

Query

select freq_interval  from sysjobschedules where name='x'

Results

59

The table sysjobschedules in MSDB database stores the freq_interval in the following manner.

1 = Sunday

2 = Monday

4 = Tuesday

8 = Wednesday

16 = Thursday

32 = Friday

64 = Saturday

In order to find what 59 means, we can write the query below or create a function using this query.

Query

select Frequency=
CASE freq_interval  &64 WHEN 64 THEN 'Saturday'+char(13)+char(10) ELSE '' END+
CASE freq_interval  &32 WHEN 32 THEN 'Friday'+char(13)+char(10) ELSE '' END+
CASE freq_interval  &16 WHEN 16 THEN 'Thursday'+char(13)+char(10) ELSE '' END+
CASE freq_interval  &8 WHEN 8 THEN 'Wednesday'+char(13)+char(10) ELSE '' END+
CASE freq_interval  &4 WHEN 4 THEN 'Tuesday'+char(13)+char(10) ELSE '' END+
CASE freq_interval  &2 WHEN 2 THEN 'Monday'+char(13)+char(10) ELSE '' END
+CASE freq_interval  &1 WHEN 1 THEN 'Sunday'+char(13)+char(10) ELSE '' END
from sysjobschedules where name ='x'

Results

Frequency

Friday
Thursday
Wednesday
Monday
Sunday

Conclusion

The main intent of this article is to analyze and understand how SQL Server uses Binary digits for categorizing and to query such categorized binary numbers to produce detailed results. SQL Server uses binary digits for categorizing in many system tables such as sysdatabases, sysjobschedules, sysdevices, etc. You can use the above method to query such binary information.

» See All Articles by Columnist MAK



MS SQL Archives

Comment and Contribute

 


(Maximum characters: 1200). You have characters left.

 

 




Latest Forum Threads
MS SQL Forum
Topic By Replies Updated
SQL 2005: SSIS: Error using SQL Server credentials poverty 3 August 17th, 07:43 AM
Need help changing table contents nkawtg 1 August 17th, 03:02 AM
SQL Server Memory confifuration bhosalenarayan 2 August 14th, 05:33 AM
SQL Server Primary Key and a Unique Key katty.jonh 2 July 25th, 10:36 AM


















Thanks for your registration, follow us on our social networks to keep up-to-date