Passing a Variable to an IN List

Every once in a while there is a need to do something like this:

SELECT person_id, person_name

FROM MyUsers

WHERE person_id IN (@search_list);

And @search_list contains some form of a delimited list. However, this is not a supported syntax and will fail. Here is one solution to this problem:

-- Create the test table

CREATE TABLE MyUsers (

 person_id INT PRIMARY KEY,

 person_name VARCHAR(35));

 

-- Insert sample data

INSERT INTO MyUsers VALUES (1327, 'Joe');

INSERT INTO MyUsers VALUES (1342, 'John F.');

INSERT INTO MyUsers VALUES (1411, 'Mary');

INSERT INTO MyUsers VALUES (1345, 'Nancy');

INSERT INTO MyUsers VALUES (1366, 'Greg');

INSERT INTO MyUsers VALUES (1367, 'Jeff');

INSERT INTO MyUsers VALUES (1368, 'Chris');

INSERT INTO MyUsers VALUES (1369, 'John M.');

INSERT INTO MyUsers VALUES (1370, 'Peggy');

INSERT INTO MyUsers VALUES (1371, 'Samuel');

INSERT INTO MyUsers VALUES (1372, 'Tony');

INSERT INTO MyUsers VALUES (1373, 'Lisa');

INSERT INTO MyUsers VALUES (1374, 'Tom');

INSERT INTO MyUsers VALUES (1375, 'Dave');

INSERT INTO MyUsers VALUES (1376, 'Peter');

INSERT INTO MyUsers VALUES (1377, 'Jason');

INSERT INTO MyUsers VALUES (1378, 'Justin');

INSERT INTO MyUsers VALUES (1379, 'Oscar');

 

DECLARE @search_list VARCHAR(100);

 

DECLARE @delimiter CHAR(1);

 

SELECT @search_list = '1327,1342,1411',

       @delimiter = ',';

 

-- Get the users based on the delimited variable list

SELECT person_id, person_name

FROM MyUsers

WHERE person_id IN

    (SELECT SUBSTRING(string, 2, CHARINDEX(@delimiter, string, 2) - 2)

      FROM (SELECT SUBSTRING(list, n, LEN(list))

            FROM (SELECT @delimiter + @search_list + @delimiter) AS L(list),

                (SELECT ROW_NUMBER() OVER (ORDER BY person_id)

                  FROM MyUsers) AS Nums(n)

            WHERE n <= LEN(list)) AS D(string)

      WHERE LEN(string) > 1

        AND SUBSTRING(string, 1, 1) = @delimiter)

ORDER BY person_id;


-- Results person_id person_name
-------- ------------------------------
1327 Joe
1342 John F.
1411 Mary

Notes:

– This algorithm is based on walking the delimited string (could be in a table column or a variable) and parsing it into a table format that can feed the IN list.

– The use of ROW_NUMBER assumes you are using SQL Server 2005. However, you can accomplish the same if you have SQL Server 2000. What this subquery does (SELECT ROW_NUMBER() OVER (ORDER BY person_id) FROM MyUsers) is simply generating a table with numbers. In SQL Server 2000 you can create a temp table and generate sequential numbers. The only requirement is that you have more numbers than the length of the string to parse (in this case the length of ‘1327,1342,1411’). These numbers are used as an index in the walk process.

SQL Server 2005 Service Pack 2

The long awaited SQL Server 2005 SP2 is released! This is important for a few reasons, not the least of which that Vista requires SP2 to run SQL Server.

It is an all inclusive service pack, which means it includes everything from service pack 1. The installation requires 1.9 GB of disk space available to download and install SP2. Upon installation it does take approximately 1 GB of disk space on the system drive.

The following table shows the version numbers that correspond to versions of SQL Server 2005:

Version Number  SQL Server 2005 Version

--------------  ---------------------------------
9.00.1399 SQL Server 2005 (initial version)
9.00.2047 SQL Server 2005 SP1
9.00.3042 SQL Server 2005 SP2
9.00.3050 SQL Server 2005 SP2a
9.00.3152 SQL Server 2005 SP2 with KB933097

The SQL Server 2005 version can be verified in SQL Server Management Studio Object Explorer when connected to the instance, or by executing the following query against a Database Engine instance:

SELECT SERVERPROPERTY('ProductVersion');

To avoid reboot after the installation it is recommended to stop the Windows Management Instrumentation and SQL Server FullText Search services.

Everyone has its preferences when it comes to new features. Here is the list of my top 10 features in this service pack:

1. VARDECIMAL – This new storage format, known as vardecimal storage format, stores decimal and numeric data as variable length columns and can be enabled or disabled at a table level on new or existing tables. If you have declared a decimal or numeric column with high precision but most values in the column do not require many digits of precision, you can potentially save a large amount of the disk space that is needed to store the table. A new stored procedure is provided to estimate the reduction in average row size with the new storage format.

2. Maintenance Plans – Maintenance plans are now supported by the SQL Server Database Services installation. Before SP2, you were required to install SQL Server 2005 Integration Services (SSIS) to run maintenance plans on a server-only installation.

3. Custom Reports – Users can now integrate their own management reports into Management Studio.

4. Linked servers – The New Linked Server dialog box now includes a Test Connection button. The Linked Servers node in Object Explorer now displays system catalogs and user database objects. As soon as the linked server is created, you can expand its node to show tables and views on the remote server.

5. Script generation – You can control how objects are scripted from the Object Explorer using the new Tools Options script dialog box. This dialog box also controls the defaults for the generate Script Wizard. Also, in the Generate Script Wizard you can now specify that the scripted objects include a DROP statement before the CREATE statement. Scripting of objects into separate files is now possible.

6. Maintenance Plan Schedules and Multi-Server – The Maintenance Plan Designer supports multiple subplans for a maintenance plan. Each subplan can have an independent schedule for maintenance tasks. Also, maintenance plans now support multi-server environments, logging to remote servers, and multiple schedules.

7. Reporting Services Integration with SharePoint – You can integrate a report server instance with Windows SharePoint Services 3.0 or Microsoft Office 2007 SharePoint Server to store, secure, access, and manage report server items from a SharePoint site. Integration features are provided jointly through SP2 and a special Reporting Services Add-in that you download and install on an instance of the SharePoint technology you are using. The new Report Viewer Web Part is included in the Reporting Services Add-in that you install on a SharePoint technology instance.

8. Graphical Show Plans – The spacing between nodes is reduced to display more plan information.

9. SQL Server Management Studio Connections – Fewer connection prompts when you open T-SQL scripts. Management Studio determines the connection of the current context.

10. Copy Database Wizard – The new wizard can discover many of the issues with dependent objects to improve reliability. A verbose logging file is created during operation and can be examined to diagnose problems with the operation. Improved reliability for online database transfers using SMO method: Stored procedures, Jobs, Packages, Messages, Endpoints, LOGINs; Permissions (explicit GRANT/DENY).

Additional resources:

How to obtain the latest service pack for SQL Server 2005
http://support.microsoft.com/kb/913089

SQL Server 2005 Service Pack 2 Download
http://www.microsoft.com/technet/prodtechnol/sql/2005/downloads/servicepacks/sp2.mspx

SQL Server 2005 Express with SP2 Download
http://msdn.microsoft.com/vstudio/express/sql/download/

What’s New in SQL Server 2005 SP2
http://download.microsoft.com/download/2/b/5/2b5e5d37-9b17-423d-bc8f-b11ecd4195b4/WhatsNewSQL2005SP2.htm

Readme Files for SQL Server 2005 SP2 and SQL Server 2005 SP2 Express Editions and Tools
http://www.microsoft.com/downloads/details.aspx?FamilyID=eb05d099-8a66-45f6-84ce-4888760d2af8&DisplayLang=en

Readme for Microsoft SQL Server 2005 Service Pack 2
http://download.microsoft.com/download/2/B/5/2B5E5D37-9B17-423D-BC8F-B11ECD4195B4/ReadmeSQL2005SP2.htm

Press Release: Microsoft Releases SQL Server 2005 Service Pack 2
http://www.microsoft.com/presspass/press/2007/feb07/02-19SQLSP2PR.mspx

A list of the bugs that are fixed in SQL Server 2005 Service Pack 2
http://support.microsoft.com/default.aspx?scid=kb;en-us;921896

JumpstartTV Video by Brian Knight: Overview and Installing SQL Server 2005 SP2
http://www.jumpstarttv.com/Media.aspx?vid=70

Feature Pack for Microsoft SQL Server 2005 – February 2007
http://www.microsoft.com/downloads/details.aspx?familyid=50b97994-8453-4998-8226-fa42ec403d17&displaylang=en

SQL Server 2005 Samples and Sample Databases (February 2007)
http://www.microsoft.com/downloads/details.aspx?familyid=E719ECF7-9F46-4312-AF89-6AD8702E4E6E&displaylang=en

SQL Server 2005 Books Online
http://www.microsoft.com/technet/prodtechnol/sql/2005/downloads/books.mspx

Reporting Services Add-in for Microsoft SharePoint
http://www.microsoft.com/downloads/details.aspx?FamilyId=1e53f882-0c16-4847-b331-132274ae8c84&DisplayLang=en

Data Mining Add-ins for Microsoft Office 2007
http://www.microsoft.com/downloads/details.aspx?FamilyId=7c76e8df-8674-4c3b-a99b-55b17f3c4c51&DisplayLang=en

Microsoft SQL Server 2005 Service Pack 2 issue: Cleanup tasks run at different intervals than intended
http://support.microsoft.com/kb/933508

Cumulative hotfix package (build 3152) for SQL Server 2005 Service Pack 2
http://support.microsoft.com/kb/933097/

SQL Server 2005 Compact Edition

While using SQL Server Compact Edition for mobile applications makes perfect sense, using it for regular desktop applications may not be the best choice. Here is a summary of pros and cons of using the Compact Edition with desktop applications.

Pros:

– Very small footprint (only 7-8 DLLs needed, no services installed, runs as in-process rather than separate service). It takes only 1.8 MB installed.
– Easy deployment. While it can be deployed using the provided Microsoft Installer file, deployment can be as simple as shipping and installing the Compact Edition DLLs to the application directory. However, this type of installation will not provide the automatic updates via Windows Update (it provides automatic updates only if installed via the MSI file).
– Support for T-SQL.
– If installed by deploying the DLLs to the application directory then there is no need for administrative user privileges (only the MSI install requires administrative privileges to register DLLs).
– Support for Remote Data Access (RDA) and ADO.NET Sync Framework. This provides convenience and flexibility to synchronize and transfer data between Compact Edition database and SQL Server databases.
– Support for different file extensions, which can help to secure the database file.
– Allows storing the database file on a network share.
– Higher safety and security because it is code free (no support for T-SQL procedural code).
– Encryption of the database file (as well as password protection) provides data security.

Cons:

– Procedural T-SQL code is not supported (stored procedures, views, triggers).
– The T- SQL language is limited (for example, no TOP, IF, ROW_NUMBER).
– No ODBC driver (although the existing ADO.NET and OLE DB data providers are sufficient from programming stand point).
– Missing role based security.
– No distributed transactions support.
– No native XML and XQuery support (XML is stored as NTEXT).
– Only 256 user connections (although this can hardly be viewed as a drawback because of the intended usage as a desktop database).

After all, the SQL Server Compact Edition is a great addition to the SQL Server family and has many benefits for particular applications. Still, to deliver flexible and rich desktop database applications, something like SQL Server 2005 Express may be a better choice.

Libraries:

The following libraries are installed on the desktop with the SQL Server Compact Edition MSI file:

– SQLCESE30.DLL
– SQLCEQP30.DLL
– SQLCEME30.DLL
– SQLCEOLEDB30.DLL (OLE DB data provider)
– SQLCECA30.DLL
– SQLCECOMPACT30.DLL
– SQLCEER30xx.DLL
– System.Data.SqlServerCe.dll (ADO.NET data provider)

Using the OLE DB provider does not require the .NET Framework, while using the ADO.NET provider requires .NET 2.0 or later (since it is using the SQL Server Native Client).

How-to:

– To connect to SQL Server Compact Edition using SQL Server Management Studio, on the login screen in SSMS you select “SQL Server Mobile” for Server type. Then browse to the database file or create a new database.

– The connection string for using in applications looks like this:
“data source=MyDatabase.sdf; ssce: mode=Exclusive;”

Here is a sample code for connecting:

SqlCeEngine eng = new SqlCeEngine();

eng.LocalConnectionString = "data source=MyDatabase.sdf; ssce: mode=Exclusive;";

Additional resources:

SQL Server 2005 Compact Edition Home:
http://www.microsoft.com/sql/editions/compact/default.mspx

SQL Server 2005 Compact Edition How-to Tutorials:
http://msdn2.microsoft.com/en-us/sql/bb219480.aspx

Convert Tree Structure From Nested Set Into Adjacency List

Tree structures are often represented in nested set model or adjacency list model. In the nested set model each node has a left and right, where the root will always have a 1 in its left column and twice the number of nodes in its right column. On the other side the adjacency list model uses a linking column (child/parent) to handle hierarchies.

Sometimes there is a need to convert a nested set model into an adjacency list model. Here is one example of doing that:

CREATE TABLE NestedSet (

 node CHAR(1) NOT NULL PRIMARY KEY,

 lf INT NOT NULL,

 rg INT NOT NULL);

 

INSERT INTO NestedSet VALUES ('A', 1, 8);

INSERT INTO NestedSet VALUES ('B', 2, 3);

INSERT INTO NestedSet VALUES ('C', 4, 7);

INSERT INTO NestedSet VALUES ('D', 5, 6);

 

CREATE TABLE AdjacencyList (

 node CHAR(1) NOT NULL PRIMARY KEY,

 parent CHAR(1) NULL);

 

INSERT INTO AdjacencyList

SELECT A.node,

       B.node AS parent

FROM NestedSet AS A

LEFT OUTER JOIN NestedSet AS B

  ON B.lf = (SELECT MAX(C.lf)

            FROM NestedSet AS C

            WHERE A.lf > C.lf

               AND A.lf < C.rg);


-- Results
node parent
------ --------
A NULL
B A
C A
D C

Additional resources:

Book: “Trees and Hierarchies in SQL for Smarties” by Joe Celko

Adjacency List Model
http://www.sqlsummit.com/AdjacencyList.htm

Trees in SQL
http://www.intelligententerprise.com/001020/celko.jhtml?_requestid=1266295

DST 2007 and SQL Server

Beginning in 2007, daylight saving time (DST) will be extended in the United States. DST will start three weeks earlier on March 11, 2007, and end one week later on November 4, 2007. This results in a new DST period that is four weeks longer than previously observed.

How that does affect SQL Server users? Since the SQL Server engine takes time from the Windows operating system, SQL Server users will not be directly affected. As long as their Windows system is updated with the appropriate patches the SQL Server engine will be fine. However, users that utilize the Notification Services for SQL Server will be affected. They need to apply the update script from this KB article: http://support.microsoft.com/?id=931815.

To determine if Notification Services is installed users can check Add/Remove Programs for SQL Server 2000 (since Notification Services is installed as a separate product) or certain registry keys can be verified for both SQL Server 2000 and 2005. Also, the existence of the NS services or databases named like NS* will be an indication for existence of Notification Services. See the section “How to determine whether Notification Services is installed” in the above KB article for more details.

Important notes:

– The update script needs to be applied only if a Notification Services instance has been deployed, since only the NS application instance database is affected. By default when Notification Services is installed it installs only the binary files (which do not need to be updated).
– New instances created after SQL Server 2005 SP2 is installed do not need to be patched (however, SQL Server SP2 does not fix existing instances, so they have to be patched).

Additional resources:

2007 time zone update for Microsoft Windows operating systems
http://support.microsoft.com/kb/928388/

Daylight Saving Time Help and Support Center
http://support.microsoft.com/gp/cp_dst

2007 time zone update for SQL Server 2005 Notification Services and for SQL Server 2000 Notification Services
http://support.microsoft.com/?id=931815

How to prepare SQL Server 2005 and SQL Server 2000 for changes to daylight saving time in 2007
http://support.microsoft.com/?kbid=931975

February 2007 cumulative time zone update for Microsoft Windows operating systems
http://support.microsoft.com/kb/931836/