![]() | ![]() | ![]() | ![]() |
SQL server tables that use sparse columns can designate a column set to return all sparse columns in the table. A column set is an untyped XML representation that combines all the sparse columns into one column. Adding a column set changes the behavior of SELECT * queries. The query returns the column set as one column and does not return the individual sparse columns.
This sample shows how to access the individual columns from SAS, using SQL pass-through. The sample uses a table in MS SQL server created as:
CREATE TABLE [class]( [name] varchar(8), [sex] varchar(1) SPARSE NULL, [age] integer SPARSE NULL, [weight] decimal(18, 2) SPARSE NULL, [height] decimal(18, 2) SPARSE NULL, [Columnset] [xml] COLUMN_SET FOR ALL_SPARSE_COLUMNS NULL)
The table contains five columns, of which four are included in a column set: sex, age, weight, and height. Two columns are returned to SAS when reading from the table using the ODBC LIBNAME engine.
Code
LIBNAME mssql ODBC dsn=data-source-name user=userid pw password; PROC CONTENTS DATA=mssql.class; RUN;
Output
Alphabetic List of Variables and Attributes # Variable Type Len Format Informat Label ------------------------------------------------------ 1 name Char 8 $8. $8. name 2 Columnset Char 1024 $1024. $1024. Columnset
SQL explicit pass-thru can be used to access the individual columns. The code below first connects to the MS SQL server, then inserts a row into the table and selects the individual columns.
Code
PROC SQL;
CONNECT TO ODBC (dsn=data-source-name user=userid pwpassword);
EXECUTE (
insert into class (name, sex, age, weight, height) values('Johan','M',12,75,100)
) BY ODBC;
SELECT * FROM CONNECTION TO ODBC(select name, sex, age, weight, height from class);
QUIT;
Output
name Columnset -------------------------------------------------------------------------------- Johan <sex>M</sex><age>12</age><weight>75.00</weight><height>100.00</height> name sex age weight height ------------------------------- Johan M 12 75.00 100.00
These sample files and code examples are provided by SAS Institute Inc. "as is" without warranty of any kind, either express or implied, including but not limited to the implied warranties of merchantability and fitness for a particular purpose. Recipients acknowledge and agree that SAS Institute shall not be liable for any damages whatsoever arising out of their use of this material. In addition, SAS Institute will provide no support for the materials contained herein.
%let DSN=sqlserver; * ODBC Data Source Name;
%let USER=user; * MS SQL Server User name;
%let PW=pw; * MS SQL Server User password;
proc sql;
connect to odbc (dsn=&DSN user=&USER pw=&PW);
execute ( drop table class ) by odbc;
execute (
CREATE TABLE [class](
[name] varchar(8),
[sex] varchar(1) SPARSE NULL,
[age] integer SPARSE NULL,
[weight] decimal(18, 2) SPARSE NULL,
[height] decimal(18, 2) SPARSE NULL,
[Columnset] [xml] COLUMN_SET FOR ALL_SPARSE_COLUMNS NULL
)
) by odbc;
execute (
insert into class (name, sex, age, weight, height) values('Johan','M',12,75,100)
) by odbc;
select * from connection to odbc (select * from class); /* Returns two columns: Name and Coloumnset */
select * from connection to odbc (select name,sex,age,weight,height from class); /* Returns Name and the individual columns in Columnset*/
quit;
libname mssql odbc dsn=&DSN user=&USER pw=&PW;
proc contents data=mssql.class;
run;
These sample files and code examples are provided by SAS Institute Inc. "as is" without warranty of any kind, either express or implied, including but not limited to the implied warranties of merchantability and fitness for a particular purpose. Recipients acknowledge and agree that SAS Institute shall not be liable for any damages whatsoever arising out of their use of this material. In addition, SAS Institute will provide no support for the materials contained herein.
| Type: | Sample |
| Date Modified: | 2012-01-19 17:48:54 |
| Date Created: | 2011-11-24 09:17:38 |
| Product Family | Product | Host | SAS Release | |
| Starting | Ending | |||
| SAS System | SAS/ACCESS Interface to ODBC | Microsoft® Windows® for 64-Bit Itanium-based Systems | ||
| Microsoft Windows Server 2003 Datacenter 64-bit Edition | ||||
| Microsoft Windows Server 2003 Enterprise 64-bit Edition | ||||
| Microsoft Windows XP 64-bit Edition | ||||
| Microsoft® Windows® for x64 | ||||
| OS/2 | ||||
| Microsoft Windows 95/98 | ||||
| Microsoft Windows 2000 Advanced Server | ||||
| Microsoft Windows 2000 Datacenter Server | ||||
| Microsoft Windows 2000 Server | ||||
| Microsoft Windows 2000 Professional | ||||
| Microsoft Windows NT Workstation | ||||
| Microsoft Windows Server 2003 Datacenter Edition | ||||
| Microsoft Windows Server 2003 Enterprise Edition | ||||
| Microsoft Windows Server 2003 Standard Edition | ||||
| Microsoft Windows Server 2003 for x64 | ||||
| Microsoft Windows Server 2008 | ||||
| Microsoft Windows Server 2008 for x64 | ||||
| Microsoft Windows XP Professional | ||||
| Windows 7 Enterprise 32 bit | ||||
| Windows 7 Enterprise x64 | ||||
| Windows 7 Home Premium 32 bit | ||||
| Windows 7 Home Premium x64 | ||||
| Windows 7 Professional 32 bit | ||||
| Windows 7 Professional x64 | ||||
| Windows 7 Ultimate 32 bit | ||||
| Windows 7 Ultimate x64 | ||||
| Windows Millennium Edition (Me) | ||||
| Windows Vista | ||||
| Windows Vista for x64 | ||||
| 64-bit Enabled AIX | ||||
| 64-bit Enabled HP-UX | ||||
| 64-bit Enabled Solaris | ||||
| AIX | ||||
| HP-UX | ||||
| HP-UX IPF | ||||
| Linux | ||||
| Linux for x64 | ||||
| Linux on Itanium | ||||
| Solaris | ||||
| Solaris for x64 | ||||
| Tru64 UNIX | ||||



