The Perl Toolchain Summit needs more sponsors. If your company depends on Perl, please support this very important event.
<!DOCTYPE HTML PUBLIC "-//W3C//DTD HTML 4.01 Transitional//EN" "http://www.w3.org/TR/html4/loose.dtd">
<HTML>
<HEAD>
<META HTTP-EQUIV="Content-Language" CONTENT="en-gb" />
<META HTTP-EQUIV="Content-Type" CONTENT="text/html; charset=utf-8" />
<STYLE TYPE="text/css">
<!--
small {font-size: 90%;}


h1 {border: 5px solid #000000;
    background-color: #DDDDDD;
    text-align: center;
   }

h2 {border: 2px solid #888888;
    background-color: #DDDDDD;
    width: 50%;
    text-align: left;
   }

h3 {border: 1px solid #BBBBBB;
    background-color: #E0E0E0;
    padding-right: 6pt;
    display: inline;
    text-align: left;
   }

h4 {background-color: #E7E0E0;
    display: inline;
    text-align: left}

pre {margin-left: 18pt;
     background-color: #E7E7E0;
     }

td {padding-left: 3px;
    padding-right: 3px;}

td.extrapad {padding-right: 20px;}

th {background-color: #CCCCCC;}

.nowrap	{white-space: nowrap;}

.remark {
   font-size:80%;font-style:italic
}

-->
</STYLE>
<SCRIPT TYPE="text/javascript">
<!--
   var useragent=navigator.userAgent.toLowerCase();
   var is_opera = useragent.indexOf("opera") != -1;
   if (is_opera)
      document.write('<STYLE TYPE="text/css"> code {font-size: 83%;} </STYLE>')
-->
</SCRIPT>
<TITLE>Win32::SqlServer</TITLE>
</HEAD>

<BODY>
<H1><A NAME="NAME">Name</A></H1>
<P>Win32::SqlServer – Access Microsoft <SMALL>SQL</SMALL> Server from Perl through <SMALL>OLE DB</SMALL>.</P>
<PRE>use Win32::SqlServer;
use Win32::SqlServer qw([<I>explicit_name</I> ...] [:DEFAULT] [:cmdstates] [:consts]
                        [:datetime] [:directions] [:providers] [:resultstyles]
                        [:returns] [:routines] [:rowstyles]);</PRE>

<P><I>explicit_name</I> is any importable routine or enumeration constant. For a
complete list of what is importable, including description of export tags, please see the
section <A HREF="#EXPORTTAGS">Exported Names and Export Tags</A>.</P>
<H1>Contents</H1>
<UL STYLE="list-style-type: none;">
<LI><B><A HREF="#OVERVIEW">Overview and Introduction</A></B>
<UL STYLE="list-style-type: none;">
<LI><A HREF="#docstructure">Structure of this Document</A></LI>
<LI><A HREF="#Prerequisites">Prerequisites and Supported Platforms</A></LI>
<LI><A HREF="#functionsummary">Summary of Functions</A></LI>
<LI><A HREF="#introerrorhandling">Error Handling</A></LI>
<LI><A HREF="#quickexamples">Quick Examples</A></LI>
</UL></LI>
<LI><B><A HREF="#datatypes">Data-Type Representation</A></B></LI>
 <LI><B><A HREF="#Initroutines">Connection Routines</A></B>
<UL STYLE="list-style-type: none;">
 <LI><A HREF="#sql_init"><SPAN CLASS="nowrap">sql_init()</SPAN></A></LI>
 <LI><A HREF="#new">new</A></LI>
 <LI><A HREF="#setloginproperty"><SPAN CLASS="nowrap">setloginproperty()</SPAN></A></LI>
 <LI><A HREF="#connect"><SPAN CLASS="nowrap">connect()</SPAN></A></LI>
 <LI><A HREF="#disconnect"><SPAN CLASS="nowrap">disconnect()</SPAN></A></LI>
 <LI><A HREF="#isconnected"><SPAN CLASS="nowrap">isconnected()</SPAN></A></LI>
</UL></LI>
 <LI><B><A HREF="#High-level">High-Level Query Functions</A></B>
<UL STYLE="list-style-type: none;">
 <LI><A HREF="#sql"><SPAN CLASS="nowrap">sql()</SPAN></A></LI>
 <LI><A HREF="#sql_one"><SPAN CLASS="nowrap">sql_one()</SPAN></A></LI>
 <LI><A HREF="#sql_sp"><SPAN CLASS="nowrap">sql_sp()</SPAN></A></LI>
 <LI><SPAN CLASS="nowrap"><A HREF="#sql_insert">sql_insert()</A></SPAN></LI>
 <LI><A HREF="#TVP">Working with Table Parameters</A></LI>
</UL></LI>
 <LI><B><A HREF="#Mid-level">Mid-Level Query Functions</A></B>
<UL STYLE="list-style-type: none;">
 <LI><A HREF="#initbatch"><SPAN CLASS="nowrap">initbatch()</SPAN></A></LI>
 <LI><A HREF="#enterparameter"><SPAN CLASS="nowrap">enterparameter()</SPAN></A></LI>
 <LI><SPAN CLASS="nowrap"><A HREF="#executebatch">executebatch()</A></SPAN></LI>
 <LI><A HREF="#definetablecolumn"><SPAN CLASS="nowrap">definetablecolumn()</SPAN></A></LI>
 <LI><A HREF="#inserttableparam"><SPAN CLASS="nowrap">inserttableparam()</SPAN></A></LI>
 <LI><A HREF="#nextresultset"><SPAN CLASS="nowrap">nextresultset()</SPAN></A></LI>
 <LI><SPAN CLASS="nowrap"><A HREF="#nextrow">nextrow()</A></SPAN><BR />
   <A HREF="#getcolumninfo"><SPAN CLASS="nowrap">getcolumninfo()</SPAN></A></LI>
 <LI><A HREF="#get_result_sets"><SPAN CLASS="nowrap">get_result_sets()</SPAN></A></LI>
 <LI><A HREF="#getoutputparams"><SPAN CLASS="nowrap">getoutputparams()</SPAN></A></LI>
 <LI><A HREF="#cancelresultset"><SPAN CLASS="nowrap">cancelresultset()</SPAN></A></LI>
 <LI><A HREF="#cancelbatch"><SPAN CLASS="nowrap">cancelbatch()</SPAN></A></LI>
 <LI><A HREF="#getcmdstate"><SPAN CLASS="nowrap">getcmdstate()</SPAN></A></LI>
 <LI><A HREF="#midlevelexamples">Mid-Level Functions Examples</A></LI>
</UL></LI>
<LI><B><A HREF="#OpenSqlFilestream"><SPAN CLASS="nowrap">OpenSqlFilestream()</SPAN></A></B></LI>
 <LI><B><A HREF="#Conversion_Routines">Character-Set Conversion Routines</A></B>
<UL STYLE="list-style-type: none;">
 <LI><A HREF="#sql_set_conversion"><SPAN CLASS="nowrap">sql_set_conversion()</SPAN></A> </LI>
 <LI><A HREF="#sql_unset_conversion"><SPAN CLASS="nowrap">sql_unset_conversion()</SPAN></A> </LI>
 <LI><A HREF="#codpage_convert"><SPAN CLASS="nowrap">codepage_convert()</SPAN></A> </LI>
</UL></LI>
 <LI><B><A HREF="#Utility_Routines">Utility Routines</A></B>
<UL STYLE="list-style-type: none;">
 <LI><A HREF="#sql_has_errors"><SPAN CLASS="nowrap">sql_has_errors()</SPAN></A></LI>
 <LI><A HREF="#sql_get_command_text"><SPAN CLASS="nowrap">sql_get_command_text()</SPAN></A></LI>
 <LI><A HREF="#sql_string"><SPAN CLASS="nowrap">sql_string()</SPAN></A></LI>
 <LI><A HREF="#sql_begin_trans"><SPAN CLASS="nowrap">sql_begin_trans(), sql_commit(), sql_rollback()</SPAN></A></LI>
</UL></LI>
 <LI><B><A HREF="#OBJECT_PROPERTIES">Object Properties</A></B></LI>
 <LI><B><A HREF="#ErrorHandling">Error Handling</A></B></LI>
 <LI><B><A HREF="#Misctopics">Miscellaneous Topics</A></B>
<UL STYLE="list-style-type: none;">
 <LI><A HREF="#EXPORTTAGS">Exported Names and Export Tags</A></LI>
   <LI><A HREF="#Versionnumbers">Getting the Win32::SqlServer Version</A></LI>
 <LI><A HREF="#QueryNotification">Using Query Notification with Win32::SqlServer</A></LI>
 <LI><A HREF="#Threads">Using Win32::SqlServer in Threaded Scripts</A></LI>
 <LI><A HREF="#BUGS">Bugs and Known Restrictions</A></LI>
</UL></LI>
 <LI><B><A HREF="#ACKNOWLEDGEMENTS">Acknowledgements</A></B></LI>
 <LI><B><A HREF="#AUTHOR">Author, Copyright and Licence</A></B></LI>
</UL>

<H1><A NAME="OVERVIEW">Overview and Introduction</A></H1>
<P>Win32::SqlServer is a module that permits you to access Microsoft <SMALL>SQL</SMALL> Server
   from Perl with full access to all (well, almost) features of <SMALL>MS SQL</SMALL>
Server using <SMALL>OLE DB</SMALL> as the underlying <SMALL>API</SMALL>. Win32::SqlServer has a high-level interface that permits you to submit an
   <SMALL>SQL</SMALL> statement or call a stored procedure and retrieve the result in one
   single function call. There are several options that you can use to specify the
   structure of the result set(s) &#8211; arrays of rows that are hashes,
   arrays or scalars; a hash keyed by the primary key of the result set;
   multiple result sets can be flattened out or you can get an array of result
   sets. There are also options to retrieve information about the columns in the
result set(s).</P>
<P>Win32::SqlServer is intended to be best choice for Perl programmers who need to access <SMALL>MS SQL</SMALL> Server from Windows,
   but who have no requirements for portability. With no generic layer in
   between, you can expect good performance. Maybe more important is that the
   interface throughout is tailored to the data types and features of <SMALL>SQL</SMALL>
   Server. A prime example is error diagnostics: with Win32::SqlServer you get full access to the
   error information from <SMALL>SQL</SMALL> Server.</P>
<P><SPAN CLASS="remark">A terminology note: <I>method</I> is a popular word in
   object-oriented terminology. But being of the old school, having learnt the
   object-oriented paradigm though Simula, I prefer to use <I>functions</I> or
   simply <I>routines</I>, and those are the words you will mainly see in this
 document. </SPAN> </P>
<H2>Note on Documented vs. Undocumented</H2>
<P>While this a long and extensive manual, you will find even more routines and
 properties if you read the source code. Given the nature of Perl, these will be
 accessible to your script if you like. However, <B>any use of undocumented
 routines is entirely unsupported</B>, and particularly I feel <B>no obligation
 to maintain backwards compatibility</B>. Such routines may be dropped,
 renamed or altered between different versions of Win32::SqlServer. Thus stay away, and if
 you don&#39;t: you have been warned!</P>
<H2><A NAME="docstructure">Structure of this Document</A></H2>
<P>This section gives a high-level overview of Win32::SqlServer for the impatient.
   I first detail what <A HREF="#Prerequisites">platforms</A> you can expect
   this module to run on. You get a list of the <A HREF="#functionsummary">functions</A>
   with their parameters without any details and a
   quick list of <A HREF="#propsummary">object properties</A>. I introduce the possibilities for <A HREF="#introerrorhandling">error handling</A>
   with Win32::SqlServer. The introductory section closes with a couple of
   <A HREF="#quickexamples">quick examples</A>
   demonstrating how to access data with Win32::SqlServer&#39;s high-level functions.</P>
<P>Next chapter discusses how Win32::SqlServer represents the <A HREF="#datatypes"><SMALL>SQL</SMALL> Server data
   types</A> in Perl. This is followed by descriptions of the functions in
   Win32::SqlServer. These are split up over no less than six chapters. <A HREF="#Initroutines">Connection functions</A>,
   <A HREF="#High-level">High-level query functions</A>. <A HREF="#Mid-level">Mid-level query functions</A>,
   <A HREF="#OpenSqlFilestream"><SPAN CLASS="nowrap">OpenSqlFilestream()</SPAN></A>,
<A HREF="#Conversion_Routines">Character-set conversion routines</A> and
   <A HREF="#Utility_Routines">Utility
   routines</A>. After the function descriptions, there is a section that
   describes all <A HREF="#OBJECT_PROPERTIES">properties</A> of the
   Win32::SqlServer
   object. Next chapter is on the important topic of
   <A HREF="#ErrorHandling">Error Handling</A>, an area where Win32::SqlServer offers
   quite a few knobs.</P>
<P>Then there is a chapter of <A HREF="#Misctopics">Miscellaneous minor topics</A>:
   <A HREF="#EXPORTTAGS">exported identifiers and export tags</A>, how to use <A HREF="#QueryNotification">Query Notification</A> with Win32::SqlServer, some information about <A HREF="#Threads">threaded scripts</A> and the inevitable tale of sorrow
   about known <A HREF="#BUGS">bugs and restrictions</A>. Finally, you find
 <A HREF="#ACKNOWLEDGEMENTS">acknowledgements</A> and <A HREF="#AUTHOR">author
   information</A>.</P>
<H2><A NAME="Prerequisites">Prerequisites and Supported Platforms</A></H2>
<DL>
   <DT><B>Hardware</B></DT>
   <DD>x86 and AMD64 are supported. </DD>
   <DT>&nbsp;</DT>
   <DT><B>Perl</B></DT>
   <DD>Perl 5.18 or later is required. </DD>
   <DT>&nbsp;</DT>
   <DT><B>Operating Systems</B></DT>
   <DD>Minimum level is Windows 7 SP1 (client O/S) and Windows 2008 R2 SP1 (server O/S). For versions before Windows 10, you need to have the update in <A HREF="https://support.microsoft.com/en-us/help/2999226/update-for-universal-c-runtime-in-windows">KB2999226</A> installed. </DD>
   <DT>&nbsp;</DT>
   <DT><B>OLE DB Provider</B></DT>
   <DD>To connect to <SMALL>SQL</SMALL> Server you need a <SMALL>OLE DB</SMALL> Provider for <SMALL>SQL</SMALL> Server. There
   are several of them, or at least there are several names (they can been seen as
   different versions of the same provider). They are here listed in reverse order of release:</DD>
   <DD>
     <UL>
       <LI><SMALL>MSOLEDBSQL</SMALL> &#8211; <A HREF="http://www.microsoft.com/download/details.aspx?id=56730">Microsoft OLE DB Driver for SQL Server</A>. Originally released in March 2018, the first release of <SMALL>OLE DB</SMALL> for SQL Server after some years of deprecation. This is the recommended provider.</LI>
       <LI><SMALL>SQLNCLI11</SMALL> &#8211; SQL Serer Native Client 11.0. The provider that ships with <SMALL>SQL</SMALL> 2012 and later versions.</LI>
       <LI><SMALL>SQLNCLI10</SMALL> &#8211; SQL Server Native Client 10.0. The provider that
       shipped with <SMALL>SQL</SMALL>&nbsp;2008.</LI>
       <LI><SMALL>SQLNCLI &#8211; SQL</SMALL> (Server) Native Client. The provider that shipped with <SMALL>SQL</SMALL>&nbsp;2005.</LI>
       <LI><SMALL>SQLOLEDB</SMALL> &#8211; The original <SMALL>OLE DB</SMALL> provider that shipped with <SMALL>SQL</SMALL> 2000 and earlier versions and still ships with all operating systems. That is, if you install no <SMALL>OLE DB</SMALL> provider on the machine, <SMALL>SQLOLEDB</SMALL> will always be there for you, but you will not have support for features added in <SMALL>SQL</SMALL> 2005 or later.</LI>
     </UL>
   </DD>
   <DT>&nbsp;</DT>
   <DT><B>SQL Server</B></DT>
   <DD>All versions from <SMALL>SQL</SMALL> Server 7 and on
   are supported. When it comes to Windows Azure SQL Database, I have not tested Win32::SqlServer on this platform, but I would expect it work.</DD>
   <DT>&nbsp;</DT>
   <DT><B>Compiler</B></DT>
   <DD>If you want to compile Win32::SqlServer on your own, you need Visual Studio 2015 or
   later. You will also need the <SMALL>SDK</SMALL> file for Microsoft OLE DB Driver for SQL Server. (Note that the SDK is not installed by default when you install the provider.) If you use any other compiler than
     Visual C++, feel free to try. I have not tested that, nor do I support it.
   If you have downloaded a binary, you do not need any compiler. </DD>
  <DT>&nbsp;</DT>   
   <DT><B>Binary Support</B></DT>
   <DD>The binary distribution includes 32-bit and 64-bit binaries for Perl 5.18, 5.20, 5.22, 5.24 and 5.26. I have tested all binaries with ActivePerl with Strawberry Perl. Note that the 32-bit binaries for Perl 5.18 and up are built with USE_64_BIT_INT and they will not run with a 32-bit Perl built without this option. Generally, I have a five-version policy for binaries. That is, when Perl 5.28 is released, you can expect me to drop support for Perl 5.18</DD>
</DL>
<P>To run Win32::SqlServer on platforms not included above, you can use older versions as follows:</P>
<UL>
  <LI>For support for Perl 5.12, 5.14 or 5.16, use <A HREF="http://www.sommarskog.se/mssqlperl/Win32-SqlServer-2.010.zip">version 2.010</A> of Win32::SqlServer.</LI>
  <LI>For support for older operating systems (Windows Vista, Windows 2008, Windows XP, Windows 2003, Windows 2000), use <A HREF="http://www.sommarskog.se/mssqlperl/Win32-SqlServer-2.010.zip">version 2.010</A> of Win32::SqlServer.</LI>
  <LI>For support for Perl 5.8 or 5.10, you can use <A HREF="http://www.sommarskog.se/mssqlperl/Win32-SqlServer-2.008.zip">version 2.008</A> of Win32::SqlServer.</LI>
  <LI>To connect to SQL Server 6.5, use <A HREF="http://www.sommarskog.se/mssqlperl/Win32-SqlServer-2.008.zip">version 2.008</A> of Win32::SqlServer.</LI>
</UL>
<H2><A NAME="functionsummary">Summary of Functions</A></H2>
<P>The functions of Win32::SqlServer fall into five groups: 1) Connection
   routines. 2) High-level query functions. 3) Mid-level query functions 4)
   Conversion routines. 5) Utility
   routines. Note that many of the parameters are optional. For the sake of
   simplicity, I have not
   indicated this in the list below. Please see the full function descriptions
   for this.</P>
<H3>Connection Routines</H3>
<DL>
<DT><B><CODE>$sqlsrv = Win32::SqlServer::sql_init($server, $user, $pw, $database,
$provider);</CODE></B></DT>
<DD>Creates a Win32::SqlServer object and connects to the specified server and database.</DD>
<DT>&nbsp;</DT>
<DT><B><CODE>$sqlsrv = Win32::SqlServer-&gt;new();</CODE></B></DT>
<DD>Creates an unconnected Win32::SqlServer object.</DD>
<DT>&nbsp;</DT>
<DT><B><CODE>$sqlsrv-&gt;setloginproperty($property, $value);</CODE></B></DT>
<DD>Sets a login property such as server, user, network packet size etc.</DD>
<DT>&nbsp;</DT>
<DT><CODE><B>$stats = $sqlsrv-&gt;connect();</B></CODE></DT>

<DD>Connects to <SMALL>SQL</SMALL> Server with the login
information <SPAN CLASS="nowrap">set through <A HREF="#setloginproperty">setloginproperty()</A></SPAN>.</DD>
<DT>&nbsp;</DT>
<DT><CODE><B>$sqlsrv-&gt;disconnect();</B></CODE></DT>

<DD>Disconnects from <SMALL>SQL</SMALL> Server.</DD>
<DT>&nbsp;</DT>
<DT><CODE><B>$ret = $sqlsrv-&gt;isconnected();</B></CODE></DT>
<DD>Reports whether you are connected to <SMALL>SQL</SMALL> Server.</DD>
</DL>
<H3>High-level Query Functions</H3>
<DL>
   <DT><CODE><B>$result = $sqlsrv-&gt;sql($batch, \@unnamed, \%named, <BR />
&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp; &nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;
   $colinfostyle, $rowstyle, $resultstyle, \@keys);</B></CODE></DT>

   <DD>Passes a single query batch to <SMALL>SQL</SMALL> Server and returns a (reference to)
   one or more result sets. The batch may have parameters marked with ? or <SMALL>T-SQL</SMALL>
   style <SPAN CLASS="nowrap"><NOMEDDLE>@variables</NOMEDDLE>
   </SPAN> with values passed in <CODE><SPAN CLASS="nowrap">\@unnamed</SPAN></CODE> and/or
   <SPAN CLASS="nowrap"><CODE>\%named</CODE></SPAN>. The parameters
   <CODE>$colinfostyle,</CODE>
   <CODE>$resultstyle</CODE>,
   <CODE>$rowstyle </CODE>and <SPAN CLASS="nowrap"><CODE>\@keys</CODE></SPAN> control the structure of the returned data.</DD>
   <DT>&nbsp;</DT>
   <DT><CODE><B>$result = $sqlsrv-&gt;sql_one($batch, \@unnamed, \%named, $rowstyle);</B></CODE></DT>
   <DD>Like <A HREF="#sql"><SPAN CLASS="nowrap">sql()</SPAN></A>, but has a built-in assertion that <CODE>$batch</CODE>
   should return
   a single row, and <CODE>croaks</CODE> if it does not.</DD>
   <DT>&nbsp;</DT>
   <DT><CODE><B>$result = $sqlsrv-&gt;sql_sp($SP, \$retval, \@unnamed, \%named,
   <BR />
&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp; &nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;
   $colinfostyle, $rowstyle, $resultstyle, \@keys);</B></CODE></DT>
   <DD>Calls the stored procedure <CODE>$SP</CODE>, else similar to <A HREF="#sql"><SPAN CLASS="nowrap">sql()</SPAN></A>. The
   return value from <CODE>$SP</CODE> is returned in <CODE>$retval</CODE>.</DD>
   <DT>&nbsp;</DT>
   <DT><CODE><B>$sqlsrv-&gt;sql_insert($table, \%data);</B></CODE></DT>

   <DD>Inserts the data in <SPAN CLASS="nowrap"><CODE>\%data</CODE></SPAN> into the table <CODE>$table</CODE>,
   using the keys in <SPAN CLASS="nowrap"><CODE>\%data</CODE></SPAN> as column names.</DD>
</DL>
<H3>Mid-level Query Access</H3>
<P>The high-level routines are implemented in Perl, and they use the mid-level
   functions implemented in C++ to access <SMALL>OLE DB</SMALL>. Occasionally, you may find
   that they give you more degrees of freedom. </P>
<DL>
   <DT><B><CODE>$sqlsrv-&gt;initbatch($cmdtext);</CODE></B></DT>
   <DD>Initiates a command batch by setting the command text. When you use the
   mid-level routines, you must always start with this function.</DD>
   <DT>&nbsp;</DT>
   <DT><B><CODE>$status = $sqlsrv-&gt;enterparameter($typename, $maxlen, $paramname,
   <BR />
&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp; &nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp; $isinput, $isoutput, $value,
   <BR />
&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp; &nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp; $prec, $scale, $typeinfo);</CODE></B></DT>
   <DD>Describes a parameter in the command batch and passes a value for the
   parameter. You must call <A HREF="#enterparameter"><SPAN CLASS="nowrap">enterparameter()</SPAN></A> once for each parameter in
   the command batch.</DD>
   <DT>&nbsp;</DT>
   <DT><CODE><B>$status = $sqlsrv-&gt;definetablecolumn($tblname, $colname,
   $nameoftype, <BR />
&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;
   $maxlen, $prec, $scale,<BR />
&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;
   $usedefault, $typeinfo);</B></CODE></DT>
   <DD>Describes a column for a table-valued parameter. When you pass a table as a
   parameter, you need to call <A HREF="#definetablecolumn"><SPAN CLASS="nowrap">definetablecolumn()</SPAN></A> once for each column in the
   table.</DD>
   <DT>&nbsp;</DT>
   <DT><CODE><B>$status = $sqlsrv-&gt;inserttableparam($tblname, $inputref);</B></CODE></DT>
   <DD>Inserts a single row into a table-valued parameter. Call it once for
   every row you want to pass.</DD>

   <DT>&nbsp;</DT>
   <DT><CODE><B>$status = $sqlsrv-&gt;executebatch(\$rows_affected);</B></CODE></DT>

   <DD>Executes the command batch you defined with <A HREF="#initbatch"><SPAN CLASS="nowrap">initbatch()</SPAN></A>,
   but does not make any result set active.</DD>
   <DT>&nbsp;</DT>
   <DT><B><CODE>$more = $sqlsrv-&gt;nextresultset(\$rows_affected);</CODE></B></DT>
   <DD>Make the next result set active. Returns a false value if there are no
   more result sets. You must call this function at least once for the batch.</DD>
   <DT>&nbsp;</DT>
   <DT><B><CODE>$more = $sqlsrv-&gt;nextrow($hashref, $arrayref);</CODE></B></DT>
   <DD>Retrieves the next row and places the data in <SPAN CLASS="nowrap"><CODE>%$hashref</CODE></SPAN>
   and <SPAN CLASS="nowrap"><CODE>@$arrayref</CODE></SPAN>. Returns false, if there are no more rows
   in the result set. </DD>
   <DT>&nbsp;</DT>
   <DT><CODE><B>$sqlsrv-&gt;getcolumninfo($hashref, $arrayref);</B></CODE></DT>
   <DD>Returns information in <SPAN CLASS="nowrap"><CODE>%$hashref</CODE></SPAN>
   and <SPAN CLASS="nowrap"><CODE>@$arrayref</CODE></SPAN> about the columns in the current result set.</DD>
   <DT>&nbsp;</DT>
   <DT><B><CODE>$result = $sqlsrv-&gt;get_result_sets($colinfostyle, $rowstyle, $resultstyle,
   \@keys);</CODE></B></DT>
   <DD>
   Rather than iterating over <A HREF="#nextresultset"><SPAN CLASS="nowrap">nextresultset()</SPAN></A> and <A HREF="#nextrow"><SPAN CLASS="nowrap">nextrow()</SPAN></A>, you can call
   <A HREF="#get_result_sets"><SPAN CLASS="nowrap">get_result_sets()</SPAN></A> to get all results in one go.</DD>
   <DT>&nbsp;</DT>
   <DT><B><CODE>$sqlsrv-&gt;getoutputparams($hashref, $arrayref);</CODE></B></DT>
         <DD>Retrieves the value of all output parameters (including the return
         value from a stored procedure) and puts the data into <SPAN CLASS="nowrap"><CODE>%$hashref</CODE></SPAN>
         and <SPAN CLASS="nowrap"><CODE>@$arrayref</CODE></SPAN>. You cannot call <A HREF="#getoutputparams"><SPAN CLASS="nowrap">getoutputparams()</SPAN></A>
         until you have retrieved all result sets and all rows.</DD>
   <DT>&nbsp;</DT>
   <DT><B><CODE>$sqlsrv-&gt;cancelbatch();</CODE></B></DT>
   <DD>Cancels the current batch, and makes Win32::SqlServer ready to accept a call to
   <A HREF="#initbatch"><SPAN CLASS="nowrap">initbatch()</SPAN></A>.</DD>
   <DT>&nbsp;</DT>
   <DT><B><CODE>$sqlsrv-&gt;cancelresultset();</CODE></B></DT>
   <DD>Moves to the end of the current result set. You still need to call
   <A HREF="#nextresultset"><SPAN CLASS="nowrap">nextresultset()</SPAN></A> to move to the
   next result set.</DD>
   </DL>
<H3><SPAN CLASS="nowrap">OpenSqlFilestream()</SPAN></H3>
<DL>
<DT><B><CODE>$fh = $sqlsrv-&gt;OpenSqlFilestream($path, $access, $context [, $options [,
$alloclen]])</CODE></B></DT>
<DD>Makes a <SMALL>FILESTREAM</SMALL> column available for access through <CODE>Win32::API</CODE>.</DD>
</DL>
<H3>Character-set Conversion Routines</H3>
<DL>
<DT><CODE><B>$sqlsrv-&gt;sql_set_conversion($client_cs, $server_cs, $direction);</B></CODE></DT>

<DD>Sets up a conversion from one code page to another.</DD>
<DT>&nbsp;</DT>
<DT><CODE><B>$sqlsrv-&gt;sql_unset_conversion($direction);</B></CODE></DT>
<DD>Removes an active code-page conversion.</DD>
<DT>&nbsp;</DT>
<DT><CODE><B>$sqlsrv-&gt;codepage_convert($string, $from_cp, $to_cp);</B></CODE></DT>
<DD>Converts <CODE>$string</CODE> from one code page to another.</DD>
</DL>
<H3>Utility Routines</H3>
<DL>
   <DT><CODE><B>$ret = $sqlsrv-&gt;sql_has_errors($keepinfo);</B></CODE></DT>
   <DD>Returns whether the command batch or stored procedure generated an error.
   Requires that you have set the <B><A HREF="#ErrInfo">ErrInfo</A></B> property <B><A HREF="#SaveMessages">SaveMessages</A></B>.</DD>
   <DT>&nbsp;</DT>
   <DT><B><CODE>$cmdtext = $sqlsrv-&gt;sql_get_command_text();</CODE></B></DT>
   <DD>Returns the text for the current command; to be used from a message
   handler.</DD>
   <DT>&nbsp;</DT>
   <DT><B><CODE>$quotedstring = $sqlsrv-&gt;sql_string($string);</CODE></B></DT>
   <DD>Quotes <CODE>$string</CODE>, doubling any embedded quote characters in
   <CODE>$string</CODE> and returns the quoted string.</DD>
   <DT>&nbsp;</DT>
   <DT><CODE><B>$sqlsrv-&gt;sql_begin_trans();</B></CODE></DT>
   <DT><CODE><B>$sqlsrv-&gt;sql_commit();</B></CODE></DT>
   <DT><B><CODE>$sqlsrv-&gt;sql_rollback();</CODE></B></DT>
   <DD>Issues <SMALL>BEGIN/COMMIT/ROLLBACK TRANSACTION</SMALL>.</DD>
</DL>
<H3><A NAME="propsummary">Summary of Properties</A></H3>
<P>Property names are case-sensitive. Win32::SqlServer is a tied hash, and if you refer to an undefined property
Win32::SqlServer <CODE>croaks</CODE>.</P>
<DL>
  <DT><B>AutoConnect</B></DT>
   <DD>When it has a true value, Win32::SqlServer will <SPAN CLASS="nowrap">connect</SPAN> and <SPAN CLASS="nowrap">disconnect</SPAN>
   automatically, if you have not connected explicitly.</DD>
   <DT>&nbsp;</DT>
   <DT><B>BinaryAsStr</B></DT>
   <DD>Controls how binary data in <SMALL>SQL</SMALL> Server is represented in Perl, as hex
   strings (the default) or binary values. </DD>
   <DT>&nbsp;</DT>
   <DT><B>CommandTimeout</B></DT>
   <DD>How long Win32::SqlServer should wait before timing out on a command. The default
   is 0, which means wait forever.</DD>
   <DT>&nbsp;</DT>
   <DT><B>DateFormat</B></DT>
   <DD>Controls how <CODE><B>datetime</B></CODE> values are formatted when <B><A HREF="#datetime">DatetimeOption</A></B> has the value
   <A HREF="#DATETIME_STRFMT"><SMALL>DATETIME_STRFMT</SMALL></A>. </DD>
   <DT>&nbsp;</DT>
   <DT><B>DatetimeOption</B></DT>
   <DD>Controls how date and time values returned from <SMALL>SQL</SMALL> Server are represented in Perl.
   Default is <SMALL>ISO</SMALL> format, <FONT COLOR="#FF0000"> <I><CODE>
   <SPAN CLASS="nowrap">YYYY-MM-DD hh:mm:ss.fffffff ±hh:mm</SPAN></CODE></I></FONT>. </DD>
   <DT>&nbsp;</DT>
   <DT><B>DecimalAsStr</B></DT>
   <DD>Controls how <CODE><B>bigint</B></CODE> (on x86 only), <CODE><B>decimal</B></CODE> and
   <CODE><B>money</B></CODE> values
   are returned from <SMALL>SQL</SMALL>
   Server are represented in Perl. Floating point (the default) or as string.</DD>
   <DT>&nbsp;</DT>
   <DT><B>ErrInfo</B></DT>
   <DD>A complex structure that controls how Win32::SqlServer reacts on (error) messages
   from <SMALL>SQL</SMALL> error. See next section for an introduction.</DD>
   <DT>&nbsp;</DT>
   <DT><B>LogHandle</B></DT>
   <DD>A file handle to which Win32::SqlServer writes the commands it passes to <SMALL>SQL</SMALL>
   Server.</DD>
   <DT>&nbsp;</DT>
   <DT><B>MsecFormat</B></DT>
   <DD>Controls how the milliseconds portion of a datetime value is formatted
   when <B><A HREF="#datetime">DatetimeOption</A></B> has the value <A HREF="#DATETIME_STRFMT"><SMALL>DATETIME_STRFMT</SMALL></A>.</DD>
   <DT>&nbsp;</DT>
   <DT><B>MsgHandler</B></DT>
   <DD>A reference to a Perl <CODE>sub</CODE> that is invoked when <SMALL>SQL</SMALL> Server
   generates a message
   (error or informational). Also invoked for some errors from
   the <SMALL>OLE DB</SMALL> provider and Win32::SqlServer itself.
   Win32::SqlServer comes with
   a default message handler, <SPAN CLASS="nowrap"><CODE>Win32::SqlServer::sql_message_handler</CODE></SPAN>. </DD>
   <DT>&nbsp;</DT>
   <DT><B>NoExec</B></DT>
   <DD>Prevents Win32::SqlServer from sending any command batches to <SMALL>SQL</SMALL>
   Server. </DD>
   <DD>&nbsp;</DD>
   <DT><B>procs</B></DT>
   <DD>A hash with parameter profiles for stored procedures, used by <A HREF="#sql_sp"><SPAN CLASS="nowrap">sql_sp()</SPAN></A> as
   a cache.</DD>
   <DT>&nbsp;</DT>
   <DT><B>PropsDebug</B></DT>
   <DD>When set, Win32::SqlServer will dump login properties and their status, in case of
   an unhandled error at login.</DD>
   <DT>&nbsp;</DT>
   <DT><B>Provider</B></DT>
   <DD>Selects which <SMALL>OLE DB</SMALL> provider to use, <SMALL>MSOLEDBSQL</SMALL>, <SMALL>SQLNCLI11</SMALL>, <SMALL>SQLNCLI10</SMALL>, <SMALL>SQLNCLI</SMALL> or <SMALL>SQLOLEDB</SMALL>. By default, Win32::SqlServer uses the most recent provider
   that is installed. That is, if <SMALL>MSOLEDBSQL</SMALL> is available, this is the default.</DD>
   <DT>&nbsp;</DT>
   <DT><B>QueryNotification</B></DT>
   <DD>A hash that specifies parameters for query notification.</DD>
   <DT>&nbsp;</DT>
   <DT><B>RowsAtATime</B></DT>
   <DD>Controls how many rows at a time <A HREF="#nextrow"><SPAN CLASS="nowrap">nextrow()</SPAN></A> requests from the <SMALL>OLE DB</SMALL>
   provider. The default is 100.</DD>
   <DT>&nbsp;</DT>
   <DT><B>SQL_version</B></DT>
   <DD>Returns the version number for the <SMALL>SQL</SMALL> Server you are connected to. This
   is a read-only property.</DD>
   <DT>&nbsp;</DT>
   <DT><B>tables</B></DT>
   <DD>A hash with table definitions, used as a cache by <A HREF="#sql_insert"><SPAN CLASS="nowrap">sql_insert()</SPAN></A>.</DD>
   <DT>&nbsp;</DT>
   <DT><B>tabletypes</B></DT>
   <DD>A hash with definition of table types, used as a cache by the
   <A HREF="#High-level">high-level routines</A> for table-valued parameters.</DD>
   <DT>&nbsp;</DT>
   <DT><B>TZOption</B></DT>
   <DD>Sets a default time-zone offset for the <B><CODE>datetimeoffset</CODE></B> data type.</DD>
   <DT>&nbsp;</DT>
   <DT><B>UserData</B></DT>
   <DD>An entry where you can save your own data in a Win32::SqlServer object.</DD>
   <DT>&nbsp;</DT>
   <DT><B>usertypes</B></DT>
   <DD>A hash with the definition of user-defined types, used as a cache by 
   <A HREF="#sql"><SPAN CLASS="nowrap">sql()</SPAN></A> and <A HREF="#sql_one"><SPAN CLASS="nowrap">sql_one()</SPAN></A>.</DD>
</DL>
<H2><A NAME="introerrorhandling">Error Handling</A></H2>
<P>When you call Win32::SqlServer, (error) messages can come from three different sources:</P>
<UL>
   <LI><SMALL>SQL</SMALL> Server.</LI>
   <LI>The <SMALL>OLE DB</SMALL> Provider.</LI>
   <LI>Win32::SqlServer itself.</LI>
</UL>
<P>The prime source for messages is <SMALL>SQL</SMALL> Server, but
   Win32::SqlServer fits provider errors and its own errors and warnings into the same
   mould. (Errors that are plain abuse of the Perl interface or internal
   errors result in the traditional <CODE>croak</CODE>.)</P>
<P>Messages can be informational, warnings or errors, as determined by the
   severity level. If the level is 11 or higher, the message is an error
   condition, else not. </P>
<P>The default behaviour of Win32::SqlServer is to print all messages. And if
   the message is an error condition, Win32::SqlServer <B> <I>aborts execution</I></B> with <CODE>
   croak</CODE>. You can trap this through the traditional exception handling in Perl by
   calling Win32::SqlServer routines with <CODE>eval</CODE> and then check <CODE>$@</CODE>. </P>
<P>However, the full story is far more sophisticated. When there is a message
   from <SMALL>SQL</SMALL> Server, Win32::SqlServer invokes the message handler defined by the
   <B><A HREF="#MsgHandler">MsgHandler</A></B> property. That is, you can establish your own callback
   routine. Now, you don&#39;t have to do this very often, because
   Win32::SqlServer
   comes with a built-in default handler, <A HREF="#ErrInfo"><SPAN CLASS="nowrap">sql_message_handler()</SPAN></A>, and this
   handler is highly configurable through the <B><A HREF="#ErrInfo">ErrInfo</A></B> property. Thus, by setting
   <B><A HREF="#ErrInfo">ErrInfo</A></B> elements, you can suppress printing, prevent
   Win32::SqlServer to abort on
   normal users errors (severity &le; 16) but still abort on fatal errors such as
   running out of disk space. You can control printing and abortion by severity
   level or by individual message numbers.</P>
<P>By setting the <B><A HREF="#SaveMessages">SaveMessages</A></B> element, you can specify that you want messages
   passed back to you in the <NOMEDDLE><B>ErrInfo</B>.<B><A HREF="#Messages">Messages</A></B></NOMEDDLE> array.
   This is necessary, if you
   turn off the default abortion behaviour and you want to check for errors with
   the function <A HREF="#sql_has_errors"><SPAN CLASS="nowrap">sql_has_errors()</SPAN></A>.</P>
<P>Say you want to do all error handling yourself, and you do not want
   <A HREF="#ErrInfo"><SPAN CLASS="nowrap">sql_message_handler()</SPAN></A> to print any
   messages and never abort execution. Here is how you would do this:</P>
<PRE>$sqlsrv-&gt;{ErrInfo}{MaxSeverity}  = 19;
$sqlsrv-&gt;{ErrInfo}{PrintLines}   = 19;
$sqlsrv-&gt;{ErrInfo}{PrintMsg}     = 19;
$sqlsrv-&gt;{ErrInfo}{PrintText}    = 19;
$sqlsrv-&gt;{ErrInfo}{SaveMessages} = 1;</PRE>

<P>Then to check for errors when you submit a command batch, you would do something
   like:</P>
<PRE>delete $sqlsrv-&gt;{ErrInfo}{Messages};
$sqlsrv-&gt;sql(&#39;blafs&#39;);
if ($sqlsrv-&gt;sql_has_errors()) {
   die &quot;there was an error\n&quot;;
}</PRE>
<P>There is a full chapter devoted to <A HREF="#ErrorHandling">error handling</A>
   with the full details on how you can configure
   <A HREF="#ErrInfo"><SPAN CLASS="nowrap">sql_message_handler()</SPAN></A>, or set up your own message handler.. This chapter also includes two
 <A HREF="#errorhandlingexamples">example scripts</A> on how to load <SMALL>SQL</SMALL> files
 with Win32::SqlServer demonstrating the use of <B><A HREF="#ErrInfo">ErrInfo</A></B>.</P>
<H2><A NAME="quickexamples">Quick Examples</A></H2>
<P>The intention of these examples is to give you a taste of how you work with
   the <A HREF="#Initroutines">connection routines</A> and the
   <A HREF="#High-level">high-level query functions</A> in Win32::SqlServer. (The chapter
   on <A HREF="#Mid-level">mid-level query functions</A> includes some examples
   on those functions.) I am not giving a full explanation of all details, but
   I&#39;m leaving that for
   the description of the functions.</P>
<P>The most of these examples runs in the Northwind database. This database does
   not ship with <SMALL>SQL</SMALL>&nbsp;2005 or later, but you can download it
   <A HREF="http://www.microsoft.com/downloads/details.aspx?FamilyId=06616212-0356-46A0-8DA2-EEBC53A68034&displaylang=en">here</A>.</P>
<H3>Example 1</H3>
<P>Here we run a parameterised query and get back a result set in the default
   format. The result set is an array. Each row is then a hash, keyed by column
   names.</P>
<PRE>use strict;
use Win32::SqlServer;

# Create object and login in one step to local server with
# integrated security.
my $sqlsrv = sql_init(undef, undef, undef, &#39;Northwind&#39;);

# Our SQL statement. The ? are placeholders for the parameters.
my $stmnt = &lt;&lt;SQLEND;
SELECT OrderID, OrderDate, Freight
FROM   Orders
WHERE  CustomerID = ?
  AND  OrderDate &gt; ?
 ORDER BY OrderID
SQLEND

# Run query. The return value is a reference to an array. The
# second parameter is an arrayref of parameter descriptions.
my $result = $sqlsrv-&gt;sql($stmnt, [[&#39;nchar(5)&#39;, &#39;BERGS&#39;],
                                   [&#39;datetime&#39;, &#39;1997-06-01&#39;]]);

# Print results. Each array entry is a hash reference.
foreach my $row (@$result) {
   print &quot;OrderID: $$row{OrderID}   &quot;;
   print &quot;OrderDate: &quot; . substr($$row{OrderDate}, 0, 10), &quot;   &quot;;
   print &quot;Freight: $$row{Freight}\n&quot;;
}</PRE>
<H3>Example 2</H3>
<P>Same query, but this time the parameters are named, and we get the columns
   into an array.</P>
<PRE>use strict;
use Win32::SqlServer;

# Create object, set database and then connect with integrated security.
my $sqlsrv = Win32::SqlServer-&gt;new;
$sqlsrv-&gt;setloginproperty(&#39;Database&#39;, &#39;Northwind&#39;);
$sqlsrv-&gt;connect();

# Our SQL statement. @ needs to be escaped, because this is an SQL @.
my $stmnt = &lt;&lt;SQLEND;
SELECT OrderID, OrderDate, Freight
FROM   Orders
WHERE  CustomerID = \@custid
  AND  OrderDate  &gt; \@fromdate
ORDER BY OrderID
SQLEND

# This time we receive the result set directly into an array. Since
# we use named parameters, the second parameter is now a hash reference.
my @result = $sqlsrv-&gt;sql($stmnt, {&#39;@custid&#39;   =&gt; [&#39;nchar(5)&#39;, &#39;BERGS&#39;],
                                   &#39;@fromdate&#39; =&gt; [&#39;datetime&#39;, &#39;1997-06-01&#39;]},
                          Win32::SqlServer::LIST);

# Print results. Each array entry is an array reference.
foreach my $row (@result) {
   print &quot;OrderID: $$row[0]   &quot;;
   print &quot;OrderDate: &quot; . substr($$row[1], 0, 10), &quot;   &quot;;
   print &quot;Freight: $$row[2]\n&quot;;
} </PRE>

<H3>Example 3</H3>
<P>
Yet a variation of the above. Here we use a colinfo style to retrieve the column
names in the query. A typical case when you want to do this is when you write
data for a file, for a query passed to you, and you don't want to make any assumptions
about the columns in the query. </P>
<PRE>use strict;
use Win32::SqlServer;

# Create object, set database and then connect with integrated security.
my $sqlsrv = Win32::SqlServer-&gt;new;
$sqlsrv-&gt;setloginproperty(&#39;Database&#39;, &#39;Northwind&#39;);
$sqlsrv-&gt;connect();

# Our SQL statement. Rather than escaping @ as above, we can put SQLEND in
# single qoutes.
my $stmnt = &lt;&lt;&#39;SQLEND&#39;;
SELECT OrderID, OrderDate, Freight
FROM   Orders
WHERE  CustomerID = @custid
  AND  OrderDate  &gt; @fromdate
ORDER BY OrderID
SQLEND

# Again we receive the result set directly into an array. We pretend
# that we don&#39;t know the name of the columns from the query, and use a
# colinfo style to get the column names.
my @result = $sqlsrv-&gt;sql($stmnt, {&#39;@custid&#39;   =&gt; [&#39;nchar(5)&#39;, &#39;BERGS&#39;],
                                   &#39;@fromdate&#39; =&gt; [&#39;datetime&#39;, &#39;1997-06-01&#39;]},
                          Win32::SqlServer::LIST,
                          Win32::SqlServer::COLINFO_NAMES);

# First print a header with the column names.
print join (&quot;\t&quot;, @{$result[0]}), &quot;\n&quot;;

# The print the values.
foreach my $row (@result[1..$#result]) {
   print join(&quot;\t&quot;, @$row), &quot;\n&quot;;
}</PRE>
<H3>Example 4</H3>
<P>Here is a query that returns a single row, and we can then receive this row
   directly into a hash.</P>
<PRE>use strict;
use Win32::SqlServer qw (SINGLEROW);

# Log in to the remote server with SQL authentication.
my $sqlsrv = new Win32::SqlServer;
$sqlsrv-&gt;setloginproperty(&#39;Server&#39;,   &#39;SVR1&#39;);
$sqlsrv-&gt;setloginproperty(&#39;Username&#39;, &#39;frits&#39;);
$sqlsrv-&gt;setloginproperty(&#39;Password&#39;, &#39;PaSsvvord&#39;);
$sqlsrv-&gt;setloginproperty(&#39;Database&#39;, &#39;Northwind&#39;);
$sqlsrv-&gt;connect();

# Our SQL statement. This time the order id is the parameter.
my $stmnt = &lt;&lt;SQLEND;
SELECT CustomerID, OrderDate, Freight
FROM   Orders
WHERE  OrderID = \@orderid
SQLEND

# Run query. Since the result is a single row, we opt to receive this row
# directly in a hash.
my %order = $sqlsrv-&gt;sql($stmnt, {orderid =&gt; [&#39;int&#39;, 10987]}, SINGLEROW);

# Print results.
print &quot;CustomerID: $order{CustomerID}   &quot;;
print &quot;OrderDate: &quot; . substr($order{OrderDate}, 0, 10), &quot;   &quot;;
print &quot;Freight: $order{Freight}\n&quot;;</PRE>

<H3>Example 5</H3>
<P>Many times when you have a single-row query, you prefer to get the results 
back in output parameters. Here is the query in Example 4 again, now with output 
parameters instead of a result set. </P>
<PRE>use strict;
use Win32::SqlServer;

# Log in to the remote server with SQL authentication.
my $sqlsrv = new Win32::SqlServer;
$sqlsrv-&gt;setloginproperty(&#39;Server&#39;,   &#39;SVR1&#39;);
$sqlsrv-&gt;setloginproperty(&#39;Username&#39;, &#39;frits&#39;);
$sqlsrv-&gt;setloginproperty(&#39;Password&#39;, &#39;PaSsvvord&#39;);
$sqlsrv-&gt;setloginproperty(&#39;Database&#39;, &#39;Northwind&#39;);
$sqlsrv-&gt;connect();

# Our SQL statement. The order id is the input parameter and then there
# are three output parameters. Again we put SQLEND in single quotes to
# be relieved from having to escape all @.
my $stmnt = &lt;&lt;&#39;SQLEND&#39;;
SELECT @custid = CustomerID, @orderdate = OrderDate, @freight = Freight
FROM   Orders
WHERE  OrderID = @orderid
SQLEND

# Run query. The output parameters must be passed by reference. (And that
# is how Win32::SqlServer knows that they are output parameters.)
my($custid, $orderdate, $freight);
$sqlsrv-&gt;sql($stmnt, {orderid   =&gt; [&#39;int&#39;,      10987],
                      custid    =&gt; [&#39;nchar(5)&#39;, \$custid],
                      orderdate =&gt; [&#39;datetime&#39;, \$orderdate],
                      freight   =&gt; [&#39;money&#39;,    \$freight]});

# Print results.
print &quot;CustomerID: $custid   &quot;;
print &quot;OrderDate: &quot; . substr($orderdate, 0, 10), &quot;   &quot;;
print &quot;Freight: $freight\n&quot;;</PRE>

<H3>&nbsp;Example 6</H3>
<P>Here we list all customer names in a one-column result set. Then we can
   receive this column as a scalar value.</P>
<PRE>use strict;
use Win32::SqlServer qw(SCALAR);

# Log in to local server with Windows authentication.
my $sqlsrv = new Win32::SqlServer;
$sqlsrv-&gt;setloginproperty(&#39;Database&#39;, &#39;Northwind&#39;);
$sqlsrv-&gt;connect();

# Our SQL statement. This time there is no parameter.
my $stmnt = &lt;&lt;SQLEND;
SELECT CompanyName
FROM   Customers
ORDER  BY CompanyName
SQLEND

# Run query. We get a reference to an array with scalar values.
my $result = $sqlsrv-&gt;sql($stmnt, SCALAR);

# Print results.
foreach my $name (@$result) {
   print &quot;$name\n&quot;;
}</PRE>
<H3>Example 7</H3>
<P>In this example, we list the number of orders and total freight per customer. This
   time we receive a result set which is keyed by the customer id.</P>
<PRE>use strict;
use Win32::SqlServer qw (:rowstyles :resultstyles); # To get HASH and KEYED.

# Log in to remote server with SQL authentication.
my $sqlsrv = Win32::SqlServer::sql_init(
                    &#39;SVR1&#39;, &#39;frits&#39;, &#39;PaSsvvord&#39;, &#39;Northwind&#39;);

# Our SQL statement.
my $stmnt = &lt;&lt;SQLEND;
SELECT CustomerID, cnt = COUNT(*), totfreight = SUM(Freight)
FROM   Orders
GROUP  BY CustomerID
SQLEND

# KEYED mandates the result set to be keyed by the data, in this case
# the CustomerID column.
my %customers = $sqlsrv-&gt;sql($stmnt, HASH, KEYED, [&#39;CustomerID&#39;]);

# Print results. Each hash entry is a hash reference keyed by column name.
foreach my $cust (sort keys %customers) {
   print &quot;CustomerID: $cust   &quot;;
   print &quot;Order count: $customers{$cust}{&#39;cnt&#39;}   &quot;;
   print &quot;Total freight: $customers{$cust}{&#39;totfreight&#39;}\n&quot;;
}</PRE>

<H3>Example 8</H3>
<P>Here is an example of running a stored procedure with a single parameter.
   This is also an example on how you can handle a query batch that returns more
   than one result set.</P>
<PRE>use strict;
use Win32::SqlServer;

# Log in to local server with SQL authentication. Use tempdb.
my $sqlsrv = Win32::SqlServer::sql_init();

# Run sp_helpdb for tempdb. Note that here we don&#39;t specify the data type
# for the parameter; sql_sp looks it up. sp_helpdb returns two result sets,
# with different structures. We therefore get the results as an array of
# result sets. Each result set is an array of rows, and rows are hashes,
# keyed by column name.
my $result = $sqlsrv-&gt;sql_sp(&#39;sp_helpdb&#39;, [&#39;tempdb&#39;],
                              Win32::SqlServer::MULTISET);

# Print results for first result set. For sp_helpdb this is a single row.
foreach my $col (keys %{$$result[0][0]}) {
   print &quot;$col: $$result[0][0]{$col}\n&quot;;
}

# And print results for the second result set. This is always two rows,
# more if you have secondary data files.
foreach my $file (@{$$result[1]}) {
   foreach my $col (keys %$file) {
      my $value = $$file{$col};
      $value = &#39;&lt;NULL&gt;&#39; if not defined $value;
      print &quot;$col: $value\n&quot;;
   }
   print &#39;-&#39; x 50 . &quot;\n&quot;;
}</PRE>
<H3>Example 9</H3>
<P>In this last example, we call a procedure with an output parameter that we
retrieve. The example also shows how you can use named and unnamed parameters.</P>
<PRE>use strict;
use Win32::SqlServer;

# Log in to local server with SQL authentication. Stay in tempdb.
my $sqlsrv = new Win32::SqlServer;
$sqlsrv-&gt;connect();

# First, create a temporary procedure, to use in the example.
$sqlsrv-&gt;sql(&lt;&lt;&#39;SQLEND&#39;);
CREATE PROCEDURE #ordercnt @custid nchar(5),
                           @fromdate datetime,
                           @no_of_orders int OUTPUT AS
SELECT @no_of_orders = COUNT(*)
FROM   Northwind..Orders
WHERE  CustomerID = @custid
   AND OrderDate &gt; @fromdate
SQLEND

# Run this procedure. We can pass positional parameters in an array. For the
# output parameter we pass a reference to a scalar that will receive the value.
my $no_of_orders;
$sqlsrv-&gt;sql_sp(&#39;#ordercnt&#39;, [&#39;BERGS&#39;, &#39;1997-06-01&#39;, \$no_of_orders]);

print &quot;There are $no_of_orders orders for BERGS later than 1997-06-01.\n&quot;;

# We can also use named parameters, by using a hash. The @ is implicit.
$sqlsrv-&gt;sql_sp(&#39;#ordercnt&#39;, {custid =&gt; &#39;ALFKI&#39;,
                              fromdate =&gt; &#39;1997-06-01&#39;,
                              no_of_orders =&gt; \$no_of_orders});
print &quot;There are $no_of_orders orders for ALFKI later than 1997-06-01.\n&quot;;

# We can even mix named and unnamed. And specify @ if we feel like.
$sqlsrv-&gt;sql_sp(&#39;#ordercnt&#39;, [&#39;VINET&#39;, &#39;1997-06-01&#39;],
                             {&#39;@no_of_orders&#39; =&gt; \$no_of_orders});
print &quot;There are $no_of_orders orders for VINET later than 1997-06-01.\n&quot;;</PRE>
<H3>More Examples</H3>
<P>There are more examples this document. Under the description of
   <A HREF="#sql_sp"><SPAN CLASS="nowrap">sql_sp()</SPAN></A>, there is <A HREF="#sqlsp_examples">one more example</A> of using this
   function. The section <A HREF="#TVP">Working with table parameters</A>, has a
whole slew of examples to show how to use table-valued parameters. The chapter of the mid-level query functions closes with
   <A HREF="#midlevelexamples">three examples</A> of using these functions. And
   the chapter on error handling has <A HREF="#errorhandlingexamples">two
   examples</A> of loading stored procedures with Win32::SqlServer.</P>

<H1><A NAME="datatypes">Data-Type Representation</A></H1>
<H2><A NAME="perlrecap">Introduction</A></H2>
<P>Note: this chapter appears here, because, well I had to place it somewhere.
   You may prefer to first read the function descriptions, and then come back
   here when you need to know how Win32::SqlServer handles a certain data type.</P>
<P>At a glance, Perl may appear to be an untyped language, but in fact it is
   dynamically typed, and a variable may change data types several time during
   its existence. These are the four the main scalar data types in Perl:</P>
<UL>
   <LI>Integer number.</LI>
   <LI>Floating-point number.</LI>
   <LI>String.</LI>
   <LI>Reference.</LI>
</UL>
<P><SPAN CLASS="remark">(Well, depending on you look at the glass, you may be able to find more
   data types. But in the context of Win32::SqlServer, these are the ones we have to
   consider.)</SPAN></P>
<P><SMALL>SQL</SMALL> on the other hand has a multitude of data types, and this chapter is
   about how Win32::SqlServer maps the <SMALL>SQL</SMALL> data types to Perl values. In some cases, there
   is only a single mapping. In other cases, there are Win32::SqlServer properties you can use to control the mapping.</P>
<P>Mapping occurs on both input and output. Input to <SMALL>SQL</SMALL> Server happens
   when you pass a Perl value as a parameter to a stored procedure or
   parameterised statement with any of the routines <A HREF="#sql"><SPAN CLASS="nowrap">sql()</SPAN></A>,
 <A HREF="#sql_sp"><SPAN CLASS="nowrap">sql_sp()</SPAN></A>, <A HREF="#sql_one"><SPAN CLASS="nowrap">sql_one()</SPAN></A>,
 <A HREF="#sql_insert"><SPAN CLASS="nowrap">sql_insert()</SPAN></A> or
   <A HREF="#enterparameter"><SPAN CLASS="nowrap">enterparameter()</SPAN></A>. (There is also the case when you pass a complete <SMALL>SQL</SMALL>
   string where you have interpolated Perl values, but in this case the mapping
   happens outside Win32::SqlServer.) </P>
<P>Output from <SMALL>SQL</SMALL> Server can happen in three different ways: 1)
   A column in a
   result set. 2) An output parameter from a stored procedure. 3) The return
   value from a stored procedure or a scalar user-defined function. The
   mapping is the same in all three cases.</P>
<P>When converting input data from Perl to <SMALL>SQL</SMALL> Server, this conversion may fail
   because the Perl value cannot be mapped to a value of the <SMALL>SQL</SMALL> data type. In
   this case, Win32::SqlServer issues a warning message through the <A HREF="#MsgHandler">current message handler</A>.
   If you attempt to execute the command
   batch, this results in an error. (You do not get an error directly for the
   conversion failure, to permit you get information of conversion failures for
   all input values.)</P>
<H2><A NAME="NULL">NULL</A></H2>
<P><SMALL>SQL</SMALL>&#39;s special value <SMALL>NULL</SMALL> always maps to Perl&#39;s special value <CODE>undef</CODE>,
   even though they don&#39;t have exactly the same semantics.</P>

<H2><A NAME="integers">bit, tinyint, smallint, int</A></H2>
<H3>Output</H3>
<P>You get an integer number in Perl from <SMALL>an SQL</SMALL> value of any these types.</P>
<H3>Input</H3>
<P>
The Perl value is auto-converted to an integer number, according to the
   standard Perl rules. Thus, a string like <CODE>&#39;9F&#39;</CODE> will be interpreted as 9 and a
   string like <CODE>&#39;ABC&#39;</CODE> as 0 (and both these strings will yield Perl&#39;s standard
   warning <I>Argument &quot;<SPAN CLASS="nowrap"><CODE>%s</CODE></SPAN>&quot; isn&#39;t number in subroutine entry</I>
   if you are running with <CODE>-w</CODE>.)</P>
<H2><A NAME="bigint">bigint</A></H2>
<P>In 32-bit Perl with 32-bit integers, <CODE><B>bigint</B></CODE> is handled in the same manner as
<A HREF="bignumbers"><CODE><B>decimal</B></CODE> and <CODE><B>money</B></CODE></A>,
see below.</P>
<P>On 64-bit or 32-bit Perl with 64-bit integers (the build option USE_64_BIT_INT set), <CODE><B>bigint</B></CODE> is handled in the same manner as <CODE>
<B>int</B></CODE>. That is, full precision of the value is retained.</P>
<H2><A NAME="float">real, float</A></H2>
<H3>Output</H3>
<P>You get a floating-point number in Perl.</P>
<H3>Input</H3>
<P>Input values are auto-converted to floating-point according to the standard
   rules in Perl.</P>

<H2><A NAME="bignumbers">decimal, numeric, <SPAN CLASS="nowrap">(small)mone</SPAN></A>y</H2>
<P>What is said here, also applies to the <CODE><B>bigint</B></CODE> data type
on 32-bit Perl with 32-bit integers, but not on 64-bit or 32-bit Perl with 64-integers, see above.</P>
<H3>Output</H3>
<P>You get back the value as a floating-point value or a string, depending on the
   boolean property <B>
   <A HREF="#DecimalAsStr">DecimalAsStr</A></B>. As the name indicates, when this property has a false
   value, you get a floating-point value, else a string. The default for <B>
   <A HREF="#DecimalAsStr">DecimalAsStr</A></B> is 0.</P>
<P>With a floating-point value, you may lose precision, whereas with a string
   value the exact number is retained. Note however, that if you then go on to
   use the number in a numeric expression in Perl, the string will be
   auto-converted to floating-point anyway. Receiving the number as a string, is
   mainly useful when:</P>
<UL>
   <LI>You are going to pass the value as-is as output in a report.</LI>
   <LI>You are going to pass the value as-is as input to a parameter of the same
      type in some other Win32::SqlServer call.</LI>
   <LI>You are using a module like Math::BigInt for your calculations.</LI>
</UL>
<H3>Input</H3>
<P>On input, Win32::SqlServer looks at the Perl data type only and does not consider <B><A HREF="#DecimalAsStr">DecimalAsStr</A></B>.</P>
<P>If the value is not a string, Win32::SqlServer handles it as a floating-point number,
   and converts the value to the target type with the <SMALL>OLE DB</SMALL> interface <I>IDataConvert</I>. If the target type cannot fit the
   Perl value, the conversion fails and Win32::SqlServer issues a warning message through the <A HREF="#MsgHandler">current
   message handler</A>. .</P>
<P>If the value is a string, the string is converted to the target data type,
   using <I>IDataConvert</I>. This interface is different from Perl, and the conversion fails if the string
   cannot be converted to the target type. <SPAN CLASS="remark">
   (Curiously though, while a string like <CODE>&#39;9E&#39;</CODE> gives an error for <B>
<CODE>decimal</CODE></B> and
   <B><CODE>money</CODE></B>, for <B><CODE>bigint</CODE></B> <I>IDataConvert</I> converts this
    value without any error to&nbsp;&#8211;&nbsp;0.)</SPAN> </P>
<P>As for the format of the string, well, the short story is: use decimal point
   as delimiter and no thousands separators. The longer story is that for <B><CODE>
   bigint</CODE></B> and <B><CODE>decimal</CODE></B>/<B><CODE>numeric</CODE></B>
   nothing else works. Whereas for <B><CODE>money</CODE></B> and <B><CODE>
   smallmoney</CODE></B>, <I>IDataConvert</I>
   appears to look at the regional settings, but if a string has only one point and
   no other separator
   this point is taken as a decimal point, even if point is a thousands separator for
   the current regional setting. Thus with regional settings set to Spanish
   (Spain), &quot;<CODE>111.999</CODE>&quot; is the decimal number 111.999 (one
   hundred and eleven point 999), where as &quot;<CODE>1.111.999</CODE>&quot;
   is 1111999 (one million one hundred eleven thousand) and &quot;<CODE>€&nbsp;111.999</CODE>&quot; is 111999
   (one hundred eleven thousand). You are now warned.</P>
<H2><A NAME="datetime">Date and time data types</A></H2>
<P><B>Note</B>: <SMALL>SQL</SMALL> 2008 introduced no less than four new data types for date and time:
<B><CODE>date</CODE></B> (date only), <B><CODE>time</CODE></B> (time only), <B><CODE>datetime2</CODE></B> (wider range and higher
precision than <B><CODE>datetime</CODE></B>) and <B><CODE>datetimeoffset</CODE></B> (date and time with a time-zone
offset). For the rest of this document, I will assume that you are familiar with
these data types. If you are not, this short introduction will have to do.</P>
<H3>Output</H3>
<P>The property <B><A HREF="#datetime">DatetimeOption</A></B> determines how
   Win32::SqlServer converts the
   value returned by <SMALL>SQL</SMALL> Server. The property
<B><A HREF="#datetime">TZOffset</A></B> can be used to shift the time-zone of a <B><CODE>datetimeoffset</CODE></B> value.</P>
<P><B>Note</B>: if you use a legacy provider, <SMALL>SQLOLEDB</SMALL> or <SMALL>SQLNCLI, SQL</SMALL> Server will
return values of the new data types as strings in <SMALL>ISO</SMALL> format, and the properties
<B><A HREF="#datetime">DatetimeOption</A></B> and <B><A HREF="#datetime">TZOffset</A></B> will never apply. They only apply
to the new data types if you use
<SMALL>SQLNCLI10</SMALL> or later. <B><A HREF="#datetime">DatetimeOption</A></B> always
applies to <B><CODE>datetime</CODE></B> and <B><CODE>smalldatetime</CODE></B> values.</P>
<P>The property <B><A HREF="#datetime">DatetimeOption</A></B> can have five different values:</P>
<DL>
   <DT><B><A NAME="DATETIME_ISO">DATETIME_ISO</A></B></DT>
   <DD>You get a string on the form <SPAN CLASS="nowrap">
   <CODE> <FONT COLOR="#DD0000"><I>YYYY-MM-DD hh:mm:ss.fffffff ±hh.mm</I></FONT></CODE></SPAN>.
   You only get the parts and decimals that are applicable to the data type in
   question. So for <B><CODE>date</CODE></B> you get <SPAN CLASS="nowrap">
   <CODE> <FONT COLOR="#DD0000"><I>YYYY-MM-DD</I></FONT></CODE></SPAN>. For
   <B><CODE>time(0)</CODE></B> you get <SPAN CLASS="nowrap">
   <CODE> <FONT COLOR="#DD0000"><I>hh:mm:ss</I></FONT></CODE></SPAN>, and for
   <B><CODE>datetime2(2)</CODE></B> you get <SPAN CLASS="nowrap">
   <CODE> <FONT COLOR="#DD0000"><I>YYYY-MM-DD hh:mm:ss.ff</I></FONT></CODE></SPAN>. Only for
   <B><CODE>datetimeoffset(7)</CODE></B> you get the full <SPAN CLASS="nowrap">
   <CODE> <FONT COLOR="#DD0000"><I>YYYY-MM-DD hh:mm:ss.fffffff ±hh.mm</I></FONT></CODE>
   &#8211;</SPAN> and only if the property <B><A HREF="#datetime">TZOffset</A></B> has not been set, see below.</DD>
   <DT>&nbsp;</DT>
   <DT><B><A NAME="DATETIME_REGIONAL">DATETIME_REGIONAL</A></B></DT>
   <DD>You get a string that is formatted according to the user&#39;s regional
   settings. For <B><CODE>date</CODE></B> values, the string will include the date portion only.
   Likewise for <B><CODE>time</CODE></B> values, the string will only include the time
   portion. For <B><CODE>datetime</CODE></B>, <B><CODE>smalldatetime</CODE></B>, <B><CODE>datetime2</CODE></B> and <B><CODE>datetimeoffset</CODE></B>,
   the time
   portion is not included if it&#39;s 00:00:00, or so it seems.
   (Win32::SqlServer uses the Automation routine <I>VarBstrFromDate </I> for
   the conversion and really has no control over this.) Note that with
   regional settings, fractions are never included in the output. For <B><CODE>datetimeoffset</CODE></B> values, the time-zone offset is included in the string,
   unless <B><A HREF="#datetime">TZOffset</A></B> is set, see below. The time-zone offsets is added by
   Win32::SqlServer itself, and is always formatted in the one and same way.</DD>
   <DT>&nbsp;</DT>
   <DT><B><A NAME="DATETIME_HASH">DATETIME_HASH</A></B></DT>
   <DD>You get a reference to hash with up to nine keys: <B>Year</B>, <B>Month</B>,
   <B>Day</B>, <B>Hour</B>, <B>Minute</B>, <B>Second</B>, <B>Fraction</B>,
   <B>TZHour</B> and <B>TZMinute</B>, each containing that part of the datetime value.
   For <B><CODE>date</CODE></B>, only <B>Year</B>, <B>Month</B> and <B>Day</B> are present in the
   hash. For <B><CODE>time</CODE></B>, the only keys to appear are <B>Hour</B>, <B>Minute</B>, <B>
   Second</B> and <B>Fraction</B>. For <B><CODE>datetime</CODE></B>, <B><CODE>datetime2</CODE></B> and <B><CODE>smalldatetime</CODE></B>,
   the first seven appear. Only for <B><CODE>datetimeoffset</CODE></B>, all nine are present, and only
   if the property <B><A HREF="#datetime">TZOffset</A></B> has not been set.
   <P>Note that the value for the <B>Fraction</B> key is in milliseconds. That is, a fractional value of 123456700 nanoseconds
   appears as 123.4567.</P>
   <P>The sign of <B>TZMinute</B> follows the sign of <B>TZHour</B>. Thus, if
   the value returned from <SMALL>SQL</SMALL> Server is <SPAN CLASS="nowrap">2007-11-11 20:11:21 -03:30</SPAN>, <B>TZHour</B>
   will be -3 and <B>TZMinute</B> is -30.</P></DD>
   <DT><B><A NAME="DATETIME_FLOAT">DATETIME_FLOAT</A></B></DT>
   <DD>You get a floating-point number that represents the number of fractional
   days since <SPAN CLASS="nowrap">1899-12-30 00:00:00.000.</SPAN> This format can be useful if
   you need to pass the datetime value to <SMALL>COM</SMALL> methods that use this form
   to represent datetime values. (Note that down in <SMALL>SQL</SMALL> Server a float value of 0 converts
   to <SPAN CLASS="nowrap">1900-01-01 00:00:00.000</SPAN>.) Obviously, the time-zone offset for a <B><CODE>datetimeoffset</CODE></B>
   value will disappear with this representation. Beware that for dates before
   <SPAN CLASS="nowrap">1899-12-30</SPAN>, the values are discontiguous, since the sign
   applies only to the integer part. For instance, -2.25 is <SPAN CLASS="nowrap">1899-12-28
   06:00</SPAN> and not <SPAN CLASS="nowrap">1899-12-27 18:00</SPAN> as a strict mathematical
   definition would give.</DD>
   <DT>&nbsp;</DT>
   <DT><B><A NAME="DATETIME_STRFMT">DATETIME_STRFMT</A></B></DT>
   <DD>You get a string formatted according to the properties <B>
   <A HREF="#datetime">DateFormat</A></B> and
   <B><A HREF="#datetime">MsecFormat</A></B>. The value of <B><A HREF="#datetime">DateFormat</A></B> is passed to the C run-time
   function <I>strftime</I> and controls how all portions of the datetime value
   is formatted, save the milliseconds (not supported by <I>strftime</I>). The
   value of <B><A HREF="#datetime">MsecFormat</A></B> is passed to <I>sprintf</I> and controls how the
   milliseconds are formatted. The default for <B><A HREF="#datetime">DateFormat</A></B> is
   <FONT COLOR="#DD0000"><I><CODE><SPAN CLASS="nowrap">%Y%m%d %H:%M:%S</SPAN></CODE></I></FONT>
   and for <B><A HREF="#datetime">MsecFormat</A></B> the default is <SPAN CLASS="nowrap"><CODE><FONT COLOR="#DD0000"><I>.%3.3d</I></FONT></CODE></SPAN>.
   While you can use these properties to get about any format you like, beware
   that Win32::SqlServer will never consider this format on input.
   <P>
   For a complete listing of the available format codes, see a reference for
   <I>strftime</I>. Here is a sample of the codes that are likely to be the most
   useful:
   </P>
   <P>
<TABLE BORDER=1 CELLPADDING=0 CELLSPACING=0>
   <TR><TD><CODE><SPAN CLASS="nowrap">%b</SPAN>, <SPAN CLASS="nowrap">%B</SPAN></CODE></TD><TD>Abbreviated/full month name.</TD></TR>
   <TR><TD><CODE><SPAN CLASS="nowrap">%c</SPAN></CODE></TD><TD>Date and time representation
      appropriate for locale.</TD></TR>
   <TR><TD><CODE><SPAN CLASS="nowrap">%d</SPAN></CODE></TD><TD>Day of month as decimal number (01 –
      31)</TD></TR>
   <TR><TD><CODE><SPAN CLASS="nowrap">%H</SPAN>, <SPAN CLASS="nowrap">%I</SPAN></CODE></TD><TD>Hour in 24/12-hour format (00 –
      23)/(01 - 12)</TD></TR>
   <TR><TD><CODE><SPAN CLASS="nowrap">%m</SPAN></CODE></TD><TD>Month as decimal number (01 – 12)</TD></TR>
   <TR><TD><CODE><SPAN CLASS="nowrap">%M</SPAN></CODE></TD><TD>Minute as decimal number (00 – 59)</TD></TR>
   <TR><TD><CODE><SPAN CLASS="nowrap">%p</SPAN></CODE></TD><TD>Current locale&#39;s <SMALL>A.M./P.M</SMALL>. indicator
      for 12-hour clock.</TD></TR>
   <TR><TD><CODE><SPAN CLASS="nowrap">%S</SPAN></CODE></TD><TD>Second as decimal number (00 – 59)</TD></TR>
   <TR><TD><CODE><SPAN CLASS="nowrap">%y</SPAN>, <SPAN CLASS="nowrap">%Y</SPAN></CODE></TD><TD>Year without/with century, as
      decimal number.</TD></TR>
   <TR><TD><CODE>%%</CODE></TD><TD>Percent sign</TD></TR>
   </TABLE>
</P>
   <P>Note: do not use codes that involve weekdays, or day number within the
      year, as Win32::SqlServer does not supply these values to <I>strftime</I>.</P>
   <P>
   The main purpose of <A HREF="#DATETIME_STRFMT"><SMALL>DATETIME_STRFMT</SMALL></A> is
   to provide compatibility with
   <A HREF="http://www.sommarskog.se/mssqlperl/mssql-sqllib.html"><SMALL>MSSQL</SMALL>::Sqllib</A>
   and this format has not been enhanced for the new data types. Specifically,
   you will not get any time-zone offset with this format for <B><CODE>datetimeoffset</CODE></B>
   values.</P></DD>
</DL>
<P>
These constants are not imported by default. To refer to them, you need
to say e.g. <CODE><SPAN CLASS="nowrap">Win32::SqlServer::DATETIME_ISO</SPAN></CODE> or
import them when you <CODE>use Win32::SqlServer</CODE>, explicitly or with an
<A HREF="#EXPORTTAGS">export tag</A>.
</P>
<H4><A NAME="TZOffset">The TZOffset property</A></H4>
<P>You can set this property to a time-zone offset on the format <I><CODE>
<FONT COLOR="#DD0000">±hh:mm</FONT></CODE></I>. Win32::SqlServer will then shift
the value returned from <SMALL>SQL</SMALL> Server to the time zone you have specified, and not
include the time-zone offset in the value. That is, if the value returned from
<SMALL>SQL</SMALL> Server is <SPAN CLASS="nowrap">2007-11-11 18:00:00 +01:00</SPAN> and you have set <B><A HREF="#datetime">TZOffset</A></B>
to -08:00, Win32::SqlServer will return <CODE><SPAN CLASS="nowrap">2007-11-11 09:00:00</SPAN></CODE>
for <SMALL>ISO</SMALL> format. <CODE>{Year =&gt; 2007, Month =&gt; 11, Day =&gt; 11, Hour =&gt; 9, Minute
=&gt; 0, Second =&gt; 0, Fraction =&gt; 0)</CODE> for <A HREF="#DATETIME_HASH"><SMALL>DATETIME_HASH</SMALL></A> and 39397.375 for
<A HREF="#DATETIME_FLOAT"><SMALL>DATETIME_FLOAT</SMALL></A>. The property is also in force for <A HREF="#DATETIME_REGIONAL"><SMALL>DATETIME_REGIONAL</SMALL></A> and
<A HREF="#DATETIME_STRFMT"><SMALL>DATETIME_STRFMT</SMALL></A>.</P>
<P>A second choice for <B><A HREF="#datetime">TZOffset</A></B> is the string &quot;<CODE>local</CODE>&quot;. With this value,
Win32::SqlServer will look up the current time-zone offset (on the client, not
on the server) and use this offset. This lookup is performed every time, to permit for
<SMALL>DST</SMALL> changes while the script is running.</P>
<H3>Input</H3>
<P>On input, Win32::SqlServer looks at the Perl data type only, and does not consider
<B><A HREF="#datetime">DatetimeOption</A></B>. It
does however consider the <B><A HREF="#datetime">TZOffset</A></B> property for <B><CODE>datetimeoffset</CODE></B> values. Please
see note at the end if you are using the <SMALL>SQLOLEDB</SMALL> or <SMALL>SQLNCLI</SMALL> provider with the
new date/time data types in <SMALL>SQL</SMALL> 2008.</P>
<DL>
   <DT><B>string value</B></DT>
   <DD>If the Perl value is a string, Win32::SqlServer performs these steps:
   <OL>
   <LI>Reads the string from the back, and if there is a time-zone offset on the form
   <CODE><I><FONT COLOR="DD0000">±hh:mm</FONT></I></CODE>,
       Win32::SqlServer saves this value and strips it from the string.</LI>
   <LI>Win32::SqlServer tries to interpret the string as an <SMALL>ISO</SMALL>-formatted date,
   according to the rules detailed below.</LI>
   <LI>If the <SMALL>ISO</SMALL> interpretation fails, Win32::SqlServer hands the string over
   to the Automation routine <I>VarDateFromStr</I> that will interpret the string
   according to regional settings. Note that this step is likely to fail if the
   string includes fractional seconds.</LI>
   <LI>If the string neither can be interpreted according to regional settings, the conversion fails and the
      <A HREF="#MsgHandler">current
      message handler</A> is invoked. Thus, Win32::SqlServer never considers the
      format defined by <B><A HREF="#datetime">DateFormat</A></B> and <B><A HREF="#datetime">MsecFormat</A></B>.
      </LI>
   </OL>
   <P>When examining whether a string may be an <SMALL>ISO</SMALL> string, Win32::SqlServer
   considers these variations:</P>
   <UL>
   <LI><I><CODE><FONT COLOR="#DD0000">YYYY-MM-DD hh:mm:ss.ffffff</FONT></CODE></I>,
   where year-month-day is mandatory. The time portion may be left out
   entirely, but if the hour appears in the string, minutes must also be
   included. Seconds and fractions are always optional. The default for all
   time parts is 0.</LI>
   <LI><I><CODE><FONT COLOR="#DD0000">YYYYMMDD hh:mm:ss.ffffff</FONT></CODE></I>,
   with the same rules as above.</LI>
   <LI><I><CODE><FONT COLOR="#DD0000">YYYY-MM-DDThh:mm:ss.ffffff</FONT></CODE></I>,
   where the year, month, day, time and minute hour are mandatory. Seconds and fractions are
   optional with a default of 0. The T represents itself, and appears in
   <SMALL>T-SQL</SMALL> in <B>convert</B> style 126.</LI>
   <LI><I><CODE><FONT COLOR="#DD0000">YYYY-MM-DDZ</FONT></CODE></I>, where the
   date is mandatory, and no time portion is not permitted. This date format
   was introduced in <SMALL>SQL</SMALL> 2005.</LI>
   <LI><I><CODE><FONT COLOR="#DD0000">hh:mm:ss.ffffff</FONT></CODE></I>, where
   hours and minutes are mandatory. For the date there is a default of
   <SPAN CLASS="nowrap">1899-12-30</SPAN> and for seconds and fractions there is a default of 0. Obviously,
   this format is mainly intended for the <B><CODE>time</CODE></B> data type.</LI>
   </UL>
   <P>If you supply portions that do not apply to the data type in question, they are simply thrown away. That is,
   hours are truncated from <B><CODE>date</CODE></B> values, seconds are truncated from
   <B><CODE>smalldatetime</CODE></B> values and superfluous decimals are truncated from fractions. Note that this behaviour is different from <SMALL>SQL</SMALL> Server which rounds
   in the latter two cases.</P>
   <P>If there was a time-zone offset in the string,
   Win32::SqlServer will supply that when it passes a <B><CODE>datetimeoffset</CODE></B> value, and
   ignore it for other data types. If there never was any time-zone offset in the string, Win32::SqlServer
   will use the time-zone specified in <B><A HREF="#datetime">TZOffset</A></B>. If neither <B><A HREF="#datetime">TZOffset</A></B> is
   set, Win32::SqlServer uses a default of +00:00, that is <SMALL>UTC</SMALL>.</P>
   <P><B>Note</B>: if you experiment, you may find more
   variations that are accepted. However, the only formats that are officially
   supported are those listed above, and those interpreted as regional settings
   by Windows. Anything else is occasional, and may yield a different result with a
   later version of
   Win32::SqlServer. This does not the least apply to two-digit years, I
   strongly recommend that you always use four-digit years.</P></DD>
<DT><B>hash reference</B></DT>
   <DD>As a hash produced by Win32::SqlServer when <B><A HREF="#datetime">DatetimeOption</A></B> is <A HREF="#DATETIME_HASH"><SMALL>DATETIME_HASH</SMALL></A>, see
   above. For all types but <B><CODE>time</CODE></B>, <B>Year</B>, <B>Month</B> and <B>Day</B> must be present in the hash,
   or else conversion will fail.
   For <B><CODE>time</CODE></B>, you must supply <B>Hour</B> and <B>Minute</B>. As on output, <B>Fraction</B> is in
   milliseconds, and to supply a fraction of 123456700 nanoseconds, you need to specify
   123.4567. As on string input, parts or decimals not relevant to the type are
   always discarded and truncated.
   <P>You can supply <B>TZHour</B> and <B>TZMinute</B> for any type, but they will only be
   considered for <B><CODE>datetimeoffset</CODE></B>. It&#39;s legal to supply <B>TZHour</B> only, in which
   case <B>TZMinute</B> is assumed to be 0. The reverse is not permitted; if
   <B>TZMinute</B> is defined and <B>TZHour</B> is missing, this is an error. Note that the
   sign of <B>TZMinute</B> follows <B>TZHour</B>; to specify the time zone offset
   <SPAN CLASS="nowrap">-03:30</SPAN>, set
   <B>TZHour</B> to -3 and <B>TZMinute</B> to -30.</P>
   <P>If you do not supply a time-zone offset for <B><CODE>datetimeoffset</CODE></B> values,
   Win32::SqlServer will use the time zone defined by <B><A HREF="#datetime">TZOffset</A></B>, or
   <SPAN CLASS="nowrap">+00:00</SPAN> if
   <B><A HREF="#datetime">TZOffset</A></B> has not been set.</P></DD>
<DT><B>numeric value</B> (integer or floating-point)</DT>
   <DD>Number of (fractional) days since <SPAN CLASS="nowrap">1899-12-30</SPAN>, thus the reverse of <A HREF="#DATETIME_FLOAT"><SMALL>DATETIME_FLOAT</SMALL></A>.
   For <B><CODE>datetimeoffset</CODE></B> values, Win32::SqlServer will use the time-zone offset
   defined by the <B><A HREF="#datetime">TZOffset</A></B> property, and if property is not defined, the
   time-zone offset will be <SPAN CLASS="nowrap">+00:00</SPAN>.</DD>
</DL>
<P><B>Note</B>: If you use the <SMALL>SQLOLEDB</SMALL> or <SMALL>SQLNCLI</SMALL> provider, the rules above
apply only to <B><CODE>datetime</CODE></B> and <B><CODE>smalldatetime</CODE></B>. For the types <B><CODE>date</CODE></B>, <B><CODE>time</CODE></B>,
<B><CODE>datetime2</CODE></B> and <B><CODE>datetimeoffset</CODE></B> that are not supported by these providers,
Win32::SqlServer will pass the value you send in as <B><CODE>nvarchar</CODE></B>, and this string
will be interpreted by <SMALL>SQL</SMALL> Server. This means that strings formatted according
to regional settings will not work, nor will hash references, nor will numeric
values. Only <SMALL>ISO</SMALL> strings will work. And even with <SMALL>ISO</SMALL> strings, you may get
different results with a legacy provider than with <SMALL>SQLNCLI10</SMALL>, since
Win32::SqlServer has somewhat different conversion rules than <SMALL>SQL</SMALL> Server. (Truncation
instead of rounding, using <SPAN CLASS="nowrap">1899-12-30</SPAN> as the default date etc.)</P>
<H2>(n)<A NAME="char">char, (n)varchar, (n)text</A></H2>
<P>For <B><CODE>(n)varchar(MAX)</CODE></B> and <B><CODE>(n)text</CODE></B>, see
   also note about <A HREF="#largetypes">large data types</A> below.</P>
<H3>Output</H3>
<P>The <SMALL>SQL</SMALL> value is a placed in a Perl string. If the data type is one of the
   Unicode data types (<B><CODE>nchar</CODE></B>, <B><CODE>nvarchar</CODE></B>, <B>
   <CODE>ntext</CODE></B>), the return string will always have the <SPAN CLASS="nowrap"><SMALL>UTF</SMALL>-8</SPAN> bit set,
   even if the string contains <SMALL>ASCII</SMALL> characters only. (But this will not matter
   to you, as long as you are programming in Perl only. At least, if my understanding of Perl&#39;s handling of Unicode is correct.)</P>
<P><B>Note</B>: if you are using the <SMALL>SQLOLEDB</SMALL> provider and <SPAN CLASS="nowrap">connect</SPAN> to <SMALL>SQL</SMALL>&nbsp;2005
or later,
   be aware of that output parameters of the types <B><CODE>varchar(MAX)</CODE></B>
   and
   <CODE><B>nvachar(MAX)</B></CODE>
   will be truncated at 8000 and 4000 characters respectively. You cannot call
   user-defined functions with a return value of these data types from <SMALL>SQLOLEDB</SMALL>.
</P>
<H3>Input</H3>
<P>The Perl value is auto-converted to a string. If the <SMALL>SQL</SMALL> data type is
   any of the non-Unicode data types (<B><CODE>char</CODE></B>, <B><CODE>varchar</CODE></B>,
   <B><CODE>text</CODE></B>), and the string is a <SPAN CLASS="nowrap"><SMALL>UTF</SMALL>-8</SPAN> string with characters
   not present in the current <SMALL>ANSI</SMALL> code page,
   Win32::SqlServer uses <I>IDataConvert</I> to
   coerce the string into the <SMALL>ANSI</SMALL> code page. Thus, if the string is <I>Dvořák</I>,
   and the <SMALL>ANSI</SMALL> code page is Latin-1,
   Win32::SqlServer will pass <I>Dvorák</I> to <SMALL>SQL</SMALL>
   Server. Characters from scripts not covered by the <SMALL>ANSI</SMALL> code page typically
   appear as ?, the default fallback character. For instance, <I><SMALL>MOCKBA</SMALL></I> in
   Cyrillic letters, results in <I>??????</I> when your <SMALL>ANSI</SMALL> code page is Latin-1.
   </P>
<H2><A NAME="binary">binary, varbinary, image</A></H2>
<P>For <B><CODE>varbinary(MAX)</CODE></B> and <B><CODE>image</CODE></B>, see
   also note about <A HREF="#largetypes">large data types</A> below.</P>
<H3>Output</H3>
<P>You always receive a binary value from <SMALL>SQL</SMALL> Server in a Perl string. However,
   the contents of this Perl string depend on the property <B><A HREF="#binary">BinaryAsStr</A></B>.
   This property can have three different settings:</P>
<DL>
   <DT><B>false</B></DT>
   <DD>The string is the binary proper, which you can interpret with <CODE>unpack</CODE>, write
   to a binary file or do whatever you want to do with it.</DD>
   <DT>&nbsp;</DT>
   <DT><B>Any true value but &#39;x&#39;</B></DT>
   <DD>You get a hex string with no leading 0x. The digits <SMALL>A-F</SMALL> are always in
   uppercase. This is the default.</DD>
   <DT>&nbsp;</DT>
   <DT><B><CODE>&#39;x&#39;</CODE></B></DT>
   <DD>A hex string preceded by 0x.</DD>
</DL>
<P><B>Note</B>: if you are using the <SMALL>SQLOLEDB</SMALL> provider and <SPAN CLASS="nowrap">connect</SPAN> to <SMALL>SQL</SMALL>&nbsp;2005
or later,
   be aware of that output parameters of the type <B><CODE><CODE></CODE>varbinary(MAX)</CODE></B>
   will be truncated at 8000 bytes. You cannot call user-defined functions with
   a return value of this data type from <SMALL>SQLOLEDB</SMALL>.
</P>
<H3>Input</H3>
<P>The input value is always auto-converted into a string. How this string
   interpreted depends on the <B><A HREF="#binary">BinaryAsStr</A></B> property.</P>
<P>If this property has a false value, the string is passed as-is as a binary
   value to <SMALL>SQL</SMALL> Server.</P>
<P>If <B><A HREF="#binary">BinaryAsStr</A></B> has a true value (the default), the string must be a hex string, with
   or without leading 0x. Win32::SqlServer attempts to convert the hex string to a binary
   value. If the conversion fails, the <A HREF="#MsgHandler">current message handler</A>
   is invoked.
</P>

<H2><A NAME="guid">uniqueidentifier</A></H2>
<H3>Output</H3>
<P>Always a string in the traditional <SMALL>GUID</SMALL> representation surrounded by braces,
   for instance <CODE><SPAN CLASS="nowrap">{902A1763-561D-4F66-85B1-D18ABE916FE0}</SPAN></CODE>.</P>
<H3>Input</H3>
<P>Must be a Perl string formatted as a <SMALL>GUID</SMALL>. Enclosing braces are permitted but
   not required. Other formats causes conversion to fail.</P>
<H2><A NAME="sql_variant">sql_variant</A></H2>
<H3>Output</H3>
<P>On output the <B><CODE>sql_variant</CODE></B> value is handled as the
   underlying base type. Thus for a datetime value, Win32::SqlServer
   will look at <B><A HREF="#datetime">DatetimeOption</A></B>, for a binary value at <B><A HREF="#binary">BinaryAsStr</A></B>
   etc.</P>
<H3>Input</H3>
<P>On input, Win32::SqlServer only supports conversion to some possible base types for the
   <SMALL>SQL</SMALL> variant value, more precisely <B><CODE>int</CODE></B>,
   <B><CODE>bigint</CODE></B>, <B><CODE>float</CODE></B>,
   <B><CODE>datetime</CODE></B>, <B><CODE>date</CODE></B>, <B><CODE>time</CODE></B>, <B><CODE>datetime2</CODE></B>, <B><CODE>datetimeoffset</CODE></B>, <B><CODE>varchar</CODE></B> and <B><CODE>nvarchar</CODE></B>.
   The conversion depends on the Perl data type of the input value:</P>
<DL>
   <DT><B>hash reference</B></DT>
   <DD>If the value is a reference to a hash, Win32::SqlServer will examine if
   the hash is a <A HREF="#DATETIME_HASH">datetime hash</A>, and in
   such case pass the value to a date/time data type in <SMALL>SQL</SMALL> Server. If the <SMALL>SQL</SMALL> Server version is <SMALL>SQL</SMALL> 2008
   or later, and the provider is <SMALL>SQLNCLI10</SMALL> or later, Win32::SqlServer will select a
   type according to this scheme:
   <UL>
         <LI>If <B>Year</B>, <B>Month</B> and <B>Date</B> an no other element is present in the hash, the data type will be <B><CODE>date</CODE></B>.
         </LI>
         <LI>If <B>Year</B>, <B>Month</B> and <B>Date</B> are present in the hash as well as
         <B>TZHour</B>, the
   type will be <B><CODE>datetimeoffset(7)</CODE></B>.</LI>
         <LI>If <B>Year</B>, <B>Month</B> and <B>Date</B> are present as well as any of the
         elements <B>Hour</B>, <B>Minute</B>, <B>Second</B> or <B>Fraction</B>,
         but <B>TZHour</B> and <B>TZMinute</B> are absent, the type will be <B><CODE>datetime2(7)</CODE></B>.</LI>
         <LI>If <B>Year</B>, <B>Month</B> and <B>Date</B> are all missing, but
         <B>Hour</B> and <B>Minute</B> are
   present, the data type will be <B><CODE>time(7)</CODE></B>.</LI>
   </UL>
   <P>If the <SMALL>SQL</SMALL> Server version is <SMALL>SQL</SMALL> 2005 or earlier, or the provider is
   <SMALL>SQLNCLI</SMALL> or earlier, Win32::SqlServer will pass the value as <B><CODE>datetime</CODE></B>, if
   the keys <B>Year</B>, <B>Month</B> and <B>Day</B> are present in the hash.</P>
   <P>For any other hash reference, an incomplete datetime hash or something
   completely different, Win32::SqlServer will pass the value as a string with
   regular Perl string representation of a hash reference, e.g. <CODE>HASH(0x01234abcd)</CODE>.
   If the required keys are present, but the values are incorrect, you may get
   an error message or the reference may silently be passed as a string.</P></DD>
   <DT><B>integer number</B></DT>
   <DD>Win32::SqlServer passes the value as an <B><CODE>int</CODE></B>. On
   64-bit Perl, if the value falls outside the boundary of <B><CODE>int</CODE></B>, Win32::SqlServer
   passes the value as <B><CODE>bigint</CODE></B>.</DD>
   <DT>&nbsp;</DT>
   <DT><B>floating-point value</B></DT>
   <DD>Win32::SqlServer passes the value as a <B><CODE>float</CODE></B>.</DD>
   <DT>&nbsp;</DT>
   <DT><B>string with the UTF-8 bit set</B></DT>
   <DD>Win32::SqlServer passes the value as <B><CODE>nvarchar</CODE></B>. (Normally,
   Perl only sets this bit if there really are characters that do not fit into
   the current 8-bit character set. However, as noted above, Win32::SqlServer always set
   this bit for output values for <B><CODE>nvarchar</CODE></B>/<B><CODE>nchar</CODE></B>/<B><CODE>ntext</CODE></B>
   data.)</DD>
   <DT>&nbsp;</DT>
   <DT><B>anything else</B></DT>
   <DD>Win32::SqlServer passes the value as <B><CODE>varchar</CODE></B>.</DD>
</DL>
<H2><A NAME="xml">xml</A> and FOR XML</H2>
<P>See also note about <A HREF="#largetypes">large data types</A> below.</P>
<H3>Output</H3>
<P>Values of the <B><CODE>xml</CODE></B> data type is passed as Unicode data. That
   is, they are passed as strings, and they will always have the <SPAN CLASS="nowrap"><SMALL>UTF</SMALL>-8</SPAN> bit set.</P>
<P>Data produced with the <SMALL>FOR XML</SMALL> clause is handled as binary
   data, and you will get a binary string or a hex string depending on the
   setting of <B>
 <A HREF="#binary">BinaryAsStr</A></B>. No, I am not pulling your legs. This is
   how <SMALL>OLE DB</SMALL> relay <SMALL>FOR XML</SMALL> data. A future version
   of Win32::SqlServer may have some setting to handle <SMALL>FOR XML</SMALL> better.</P>
<P><B>Note</B>: when using the <SMALL>SQLOLEDB</SMALL> provider you cannot call a procedure
   through <A HREF="#sql_sp"><SPAN CLASS="nowrap">sql_sp()</SPAN></A>, that has an <SMALL>OUTPUT</SMALL>
   parameter of the <B><CODE>xml</CODE></B> data type. The same applies scalar
   user-defined functions of which the return type is <B><CODE>xml</CODE></B>.</P>
<H3>Input</H3>
<P>The input value must be a string that is a legal <SMALL>XML</SMALL> fragment, or else
   conversion fails. As for specifying a schema collection, please see the
   description of the functions <A HREF="#sql"><SPAN CLASS="nowrap">sql()</SPAN></A> and
 <A HREF="#enterparameter"><SPAN CLASS="nowrap">enterparameter()</SPAN></A>.</P>
<P>An <SMALL>XML</SMALL> document can include a character-set specification, which always
   appears first in the document as in this example:</P>
<PRE>&lt;?xml version=&quot;1.0&quot; encoding=&quot;utf-8&quot;?&gt;&lt;ROOT&gt;Text&lt;/ROOT&gt;</PRE>
<P>Win32::SqlServer inspects an input value of the <B><CODE>xml</CODE></B> data type, to
   see if there is a charset specification, to determine how it should pass the
   <SMALL>XML</SMALL> document to <SMALL>SQL</SMALL> Server. The following applies:</P>
<UL>
   <LI>If there is no charset encoding, Win32::SqlServer assumes that the document is
      encoded in <SPAN CLASS="nowrap"><SMALL>UTF-8</SMALL></SPAN> as per the default in the <SMALL>XML</SMALL> standard.</LI>
   <LI>If the encoding is not any of <SMALL><SPAN CLASS="nowrap">UTF-8</SPAN>, <SPAN CLASS="nowrap">UTF-16</SPAN></SMALL> or <SPAN CLASS="nowrap"><SMALL>UCS-2</SMALL></SPAN>,
      Win32::SqlServer assumes that
      the encoding is an eight-bit or multi-byte encoding and clears any <SPAN CLASS="nowrap"><SMALL>UTF-8</SMALL></SPAN>
      bit for the Perl value, and coerces it into the current <SMALL>ANSI</SMALL> code page, as
      discussed for the <A HREF="#char">character</A> data types above. (Thus if
      you know you are reading an <SMALL>XML</SMALL> document which has an eight-bit encoding
      different from your <SMALL>ANSI</SMALL> page, you should change the encoding to <SPAN CLASS="nowrap"><SMALL>UTF-8</SMALL></SPAN>, before passing it to Win32::SqlServer.)</LI>
   <LI>If the encoding is <SPAN CLASS="nowrap"><SMALL>UTF-8</SMALL></SPAN>, and you are using a log file,
      Win32::SqlServer will not
      include the encoding specification in the <A HREF="#LogHandle">log file</A>,
      as the log file would not be executable then. (Because in <SMALL>T-SQL</SMALL> there is
      no data type that can hold values in <SPAN CLASS="nowrap"><SMALL>UTF-8</SMALL></SPAN>.)</LI>
   <LI>If the encoding is <SPAN CLASS="nowrap"><SMALL>UTF-8</SMALL></SPAN> and you are using the <SMALL>SQLOLEDB</SMALL> provider,
      Win32::SqlServer
      will replace the encoding with <SPAN CLASS="nowrap"><SMALL>UCS-2</SMALL></SPAN> before passing it to <SMALL>SQL</SMALL> Server, as
      with <SMALL>SQLOLEDB</SMALL>, Win32::SqlServer must pass the value as <B><CODE>ntext</CODE></B>,
      and thus as <SPAN CLASS="nowrap"><SMALL>UCS-2</SMALL></SPAN>.</LI>
</UL>
<H2><A NAME="CLR_UDTs">CLR UDTs</A></H2>
<P>What is said here, applies both to built-in <SMALL>CLR</SMALL> types such as <B><CODE>hierarchyid</CODE></B>
and user-defined <SMALL>CLR</SMALL> types. To muddle the waters, Win32::SqlServer tend to refer
to both kinds as <SMALL>UDT</SMALL>s.</P>
<H3>Output</H3>
<P>The value is handled as a binary value, according to the setting of <B>
   <A HREF="#binary">BinaryAsStr</A></B>.</P>
<P><B>Note</B>: when using the <SMALL>SQLOLEDB</SMALL> provider you cannot call a procedure
   through <A HREF="#sql_sp"><SPAN CLASS="nowrap">sql_sp()</SPAN></A>, that has an <SMALL>OUTPUT</SMALL>
   parameter of some <SMALL>CLR</SMALL> user-defined data type. The same applies scalar
   user-defined functions of which the return type is a <SMALL>CLR UDT</SMALL>.</P>
<H3>Input</H3>
<P>The value is handled as a binary value, according to the setting of <B>
 <A HREF="#binary">BinaryAsStr</A></B>. Note that the binary value must map to a
   proper serialisation of the <SMALL>UDT</SMALL>. See the description of the functions
 <A HREF="#sql"><SPAN CLASS="nowrap">sql()</SPAN></A> and <A HREF="#enterparameter"><SPAN CLASS="nowrap">enterparameter()</SPAN></A> for how
   to actually specify the name of a <SMALL>CLR UDT</SMALL>.</P>
<H3>Large CLR UDTs</H3>
<P>Large <SMALL>CLR UDT</SMALL>s are types that are defined with MaxByteSize&nbsp;=&nbsp;-1, and thus can
exceed 8000 bytes. Large <SMALL>UDT</SMALL>s were added in <SMALL>SQL</SMALL>&nbsp;2008, and as long as you are
using <SMALL>SQLNCLI10</SMALL> or later, Win32::SqlServer handles large UDTs in the same way as regular
UDTs. (But see the general caveats on large types below).</P>
<P>If you use <SMALL>SQLNCLI</SMALL>, you cannot receive <SMALL>OUTPUT</SMALL> parameters of large <SMALL>UDT</SMALL>s, but
you can still pass values to input parameters of large <SMALL>UDT</SMALL>s. If you use
<SMALL>SQLOLEDB</SMALL>, you cannot use parameters of large <SMALL>UDT</SMALL>s at all, neither for input nor
for output. You can still receive large <SMALL>UDT</SMALL> data in result sets with any
provider.</P>
<H2><A NAME="table">table</A></H2>
<P><SMALL>SQL</SMALL> 2008 adds the possibility to pass data in table-valued parameters; only
for input, you cannot retrieve data this way. The way you pass a table-valued
parameter is quite different between the high-level routines and the mid-level
routines. </P>
<P>With the <A HREF="#High-level">high-level routines</A>, you pass an array of
rows and each row is represented by a hash or an array of column values. You don&#39;t have to
provide any definitions of the table type, as Win32::SqlServer will retrieve the
table-type definition from the server on first reference, and cache the
definition. See further the section <A HREF="#TVP">Working with Table
Parameters</A>.</P>
<P>With the <A HREF="#Mid-level">mid-level routines</A> you first need to define
the columns of the table type with <A HREF="#definetablecolumn"><SPAN CLASS="nowrap">definetablecolumn()</SPAN></A>, and you need do it every
time you pass a table-valued parameter. You then pass each row with a call to
<A HREF="#inserttableparam"><SPAN CLASS="nowrap">inserttableparam()</SPAN></A>. As with the high-level routines, a row is a hash or an array
of column values. See further the description of these routines, as well as the
description of <A HREF="#enterparameter"><SPAN CLASS="nowrap">enterparameter()</SPAN></A>.</P>
<P>You can only use table-valued parameters if you use the <SMALL>SQLNCLI10</SMALL> provider or
later; you cannot use table parameters with older providers.</P>
<H2><A NAME="largetypes">Large Data Types</A></H2>
<P>Large data types are types that may exceed 8000 bytes, that is <B><CODE>text</CODE></B>,
   <B><CODE>ntext</CODE></B>,
 <B><CODE>image</CODE></B>, <B><CODE>varchar(MAX)</CODE></B>, <CODE><SPAN CLASS="nowrap"><B>
   nvarchar(MAX)</B></SPAN></CODE>,
   <CODE><SPAN CLASS="nowrap"><B>varbinary(MAX)</B></SPAN></CODE>, <B><CODE>xml</CODE></B> and
<SMALL>CLR</SMALL> types with MaxByteSize&nbsp;=&nbsp;-1.</P>
<P>Win32::SqlServer has no particular support for these data types, but these are handled
   as just as any other types. This should be OK for values of moderate size.
   However, with values of several megabytes, the performance becomes
   unacceptable, and it can take several seconds to retrieve a 10&nbsp;MB value. </P>
<P>I hope that a future version of Win32::SqlServer will
   provide better options to deal with large
   values.</P>
<P>If you work with <SMALL>FILESTREAM</SMALL> data, you can use the <A HREF="#OpenSqlFilestream"><SPAN CLASS="nowrap">OpenSqlFilestream()</SPAN></A> interface
which Win32::SqlServer exposes.</P>
<H1><A NAME="Initroutines">Connection Routines</A></H1>
<P>There are two ways to create a Win32::SqlServer object. One is to use
   <A HREF="#sql_init"><SPAN CLASS="nowrap">sql_init()</SPAN></A>, which creates an object and connects to the
   database in one go. The other way is to use the traditional
   <A HREF="#new">new()</A> method, and the use the function <A HREF="#setloginproperty"><SPAN CLASS="nowrap">setloginproperty()</SPAN></A> to set server,
   database etc. You  connect with
   <SPAN CLASS="nowrap">
   <A HREF="#connect">connect()</A> &#8211;</SPAN> or you set the property <B>
   <A HREF="#AutoConnect">AutoConnect</A></B> which means that Win32::SqlServer connects
   and disconnects for
   each query.</P>
<H2><A NAME="sql_init"><SPAN CLASS="nowrap">sql_init()</SPAN></A></H2>
<P>Creates a Win32::SqlServer object, connects to <SMALL>SQL</SMALL> Server and returns the object.</P>
<PRE>$sqlsrv = [Win32::SqlServer::]sql_init([$server, [$username,[$password,
                                       [$database, [$provider]]]]]);</PRE>
<DL>
   <DT><CODE>$sqlsrv</CODE></DT>
   <DD>A newly created Win32::SqlServer object.</DD>
   <DT>&nbsp;</DT>
   <DT><CODE>$server</CODE></DT>
   <DD>The server to connect to. Default is the local server.</DD>
   <DT>&nbsp;</DT>
   <DT><CODE>$username</CODE></DT>
   <DD>User name for <SMALL>SQL</SMALL> authentication. The default is to connect with Windows
   Authentication.</DD>
   <DT>&nbsp;</DT>
   <DT><CODE>$password</CODE></DT>
   <DD>Password to use when you also have specified <CODE>$username</CODE>. Ignored when
   <CODE>$username</CODE> is <CODE>undef</CODE>.</DD>
   <DT>&nbsp;</DT>
   <DT><CODE>$database</CODE></DT>

   <DD>Database to connect to. Default is <B>tempdb</B>. <I>That is, the default database for
   the login is not honoured</I>.</DD>
   <DT>&nbsp;</DT>
   <DT><CODE>$provider</CODE></DT>

   <DD>Which provider to connect with. Default is <A HREF="#PROVIDER_DEFAULT"><SMALL>PROVIDER_DEFAULT</SMALL></A>. Specify any
   of the values permitted for the <B><A HREF="#Provider">Provider</A></B>
   attribute.</DD>
</DL>
<P>All parameters are optional, but in order to specify <CODE>$database</CODE>
only, you need to specify <CODE>undef</CODE> for the first three. Since this is 
a module routine, you are supposed to call it as <CODE><SPAN CLASS="nowrap">Win32::SqlServer::sql_init()</SPAN></CODE>, 
but for now <CODE><SPAN CLASS="nowrap">Win32::SqlServer-&gt;sql_init()</SPAN></CODE> works as well.</P>
<P>If the login fails, this aborts execution of the Perl script. You can only
   catch this condition with <CODE>eval</CODE>. If you want to handle login
   failures in a <A HREF="#MsgHandler">message handler</A>, create the
   Win32::SqlServer object
   with <A HREF="#new"><SPAN CLASS="nowrap">new()</SPAN></A> and set <B><A HREF="#ErrInfo">ErrInfo</A></B> elements (or
   define <A HREF="#MsgHandler">your own message handler</A>) and then use
<A HREF="#setloginproperty"><SPAN CLASS="nowrap">setloginproperty()</SPAN></A> and connect described below.</P>
<P>Win32::SqlServer saves the first object you create with <A HREF="#sql_init"><SPAN CLASS="nowrap">sql_init()</SPAN></A>, and then uses this a
   default handle, so you when say things like:</P>
<PRE>sql(&#39;SET NOUCOUNT ON&#39;);</PRE>
<P>without any <CODE><SPAN CLASS="nowrap">$sqlsrv-&gt;</SPAN></CODE> in front, Win32::SqlServer will use
   the default handle. However, this
   functionality exists only to provide compatibility with the older module <SMALL><A HREF="http://www.sommarskog.se/mssqlperl/mssql-sqllib.html">MSSQL</A></SMALL><A HREF="http://www.sommarskog.se/mssqlperl/mssql-sqllib.html">::Sqllib</A> and
   is deprecated. If you want to refer to <A HREF="#sql"><SPAN CLASS="nowrap">sql()</SPAN></A>,
   <A HREF="#sql_sp"><SPAN CLASS="nowrap">sql_sp()</SPAN></A> etc this way, you need to import
   them explicitly when you <CODE>use Win32::SqlServer</CODE> or use an <A HREF="#EXPORTTAGS">export tag</A>. Note that it is only the functions of which the name
   starts with sql_ that you can use in this way. For <A HREF="#setloginproperty"><SPAN CLASS="nowrap">setloginproperty()</SPAN></A>, <A HREF="#connect"><SPAN CLASS="nowrap">connect()</SPAN></A>,
   <A HREF="#disconnect"><SPAN CLASS="nowrap">disconnect()</SPAN></A>, <A HREF="#isconnected"><SPAN CLASS="nowrap">isconnected()</SPAN></A> and the <A HREF="#Mid-level">mid-level query functions</A> you must always specify the
   Win32::SqlServer
   object.</P>
<H2><A NAME="new">new</A></H2>
<P>Creates an un-connected Win32::SqlServer object.</P>
<PRE>$sqlsrv = new Win32::SqlServer;</PRE>
<H2><A NAME="setloginproperty"><SPAN CLASS="nowrap">setloginproperty()</SPAN></A></H2>
<P>Sets a login property such as server, database, packet size etc.</P>
<PRE>$sqlsrv-&gt;setloginproperty($property, $value);</PRE>
<DL>
   <DT><CODE>$property</CODE></DT>

   <DD>The name of a login property. See below for a list of available
   properties. Names of login properties are not case-sensitive.</DD>
   <DT>&nbsp;</DT>
   <DT><CODE>$value</CODE></DT>
   <DD>The value to set for the property. The type of the value depends on the
   property. </DD>
</DL>
<P>You can only set a login property when you are disconnected. (So you don&#39;t
   get the idea that they would have any effect on the existing connection.) If you try to set a
   property when you are connected, Win32::SqlServer <CODE>croaks</CODE>. You can check
   whether you are connected with <A HREF="#isconnected"><SPAN CLASS="nowrap">isconnected()</SPAN></A>.</P>
<P>Each login property maps to an <SMALL>OLE DB</SMALL> authorisation or initialisation
   property, either a general <SMALL>OLE DB</SMALL> property (names starting with
   <SMALL>DBPROP_</SMALL>) or
   an <SMALL>SQL</SMALL> Server-specific property (names starting with
   <SMALL>SSPROP_</SMALL>). I will have to
   admit that for some of these, I have only a vague notion of what they are
   good for. So I will have to refer you to Books Online for complete
   description in several cases. A start is the topic <A HREF="https://docs.microsoft.com/en-us/sql/connect/oledb/applications/using-connection-string-keywords-with-oledb-driver-for-sql-server"><I>Using Connection String Keywords with OLE DB Driver for SQL Server</I></A> in Books Online.</P>
<P>Not all <SMALL>OLE DB</SMALL> properties are exposed by <A HREF="#setloginproperty"><SPAN CLASS="nowrap">setloginproperty()</SPAN></A>, as not all are
   applicable in the context of Win32::SqlServer. Note below that when I say that
   Win32::SqlServer does not set a default value for a
   property, this means that any default value set by the <SMALL>OLE DB</SMALL> provider
   applies. The same applies if you set a property to <CODE>undef</CODE> – this
   means that Win32::SqlServer will not set it, leaving room for whatever default value
the provider fancies.</P>

<H3><A NAME="ApplicationIntent">ApplicationIntent</A></H3>
<P>
<TABLE BORDER=1 CELLSPACING=0 CELLPADDING=0>
<TR><TH><SPAN CLASS="nowrap">Data type</SPAN></TH><TD CLASS="extrapad">string</TD><TH>Default</TH><TD CLASS="extrapad">
   &quot;ReadWrite&quot;</TD>
    <TH><SPAN CLASS="nowrap"><SMALL>OLE DB</SMALL> Property</SPAN></TH><TD CLASS="extrapad">
   <SMALL>SSPROP_INIT_APPLICATIONINTENT</SMALL></TD></TR>
</TABLE>
</P>
<P> This parameter is applicable when connecting to an Availability Group with a 
read-only replica in <SMALL>SQL</SMALL> Server 2012 or later, and controls whether you are 
directed to the main instance or the read-only replica. The possible values are
<I>ReadWrite</I> (the default) and <I>ReadOnly</I>. This property is only 
available with the <SMALL>SQLNCLI11</SMALL> provider or later.</P>
<H3><A NAME="Appname">Appname</A></H3>
<P>
<TABLE BORDER=1 CELLSPACING=0 CELLPADDING=0>
<TR><TH><SPAN CLASS="nowrap">Data type</SPAN></TH><TD CLASS="extrapad">string</TD><TH>Default</TH><TD CLASS="extrapad">
   name of your Perl script, excluding directory path</TD>
    <TH><SPAN CLASS="nowrap"><SMALL>OLE DB</SMALL> Property</SPAN></TH><TD CLASS="extrapad"><SMALL>SSPROP_INIT_APPNAME</SMALL></TD></TR>
</TABLE>
</P>
<P> A string that represents the application name, and which can be retrieved
    in <SMALL>SQL</SMALL> Server with the <SPAN CLASS="nowrap"><SMALL>APP_NAME</SMALL>()</SPAN> function. If you
    set it to <CODE>undef</CODE>, <SMALL>OLE DB</SMALL> will apply it&#39;s default, which will be
    <I>ActivePerl</I> or somesuch.</P>

<H3><A NAME="AttachFilename">AttachFilename</A></H3>
<P>
<TABLE BORDER=1 CELLSPACING=0 CELLPADDING=0>
<TR><TH>Data type</TH><TD CLASS="extrapad">string</TD><TH>Default</TH><TD CLASS="extrapad"><CODE>undef</CODE></TD>
    <TH><SMALL>OLE DB</SMALL> Property</TH><TD CLASS="extrapad"><SMALL>SSPROP_INIT_FILENAME</SMALL></TD></TR>
</TABLE>
</P>
<P> The name of the primary database file for a database. In case the
 database you specify with <B><A HREF="#LogpropDatabase">Database</A></B> is not
   available, then <SMALL>SQL</SMALL> Server looks for this file and attaches it. </P>

<H3><A NAME="Autotranslate">Autotranslate</A></H3>
<P>
<TABLE BORDER=1 CELLSPACING=0 CELLPADDING=0>
<TR><TH>Data type</TH><TD CLASS="extrapad">boolean</TD><TH>Default</TH><TD CLASS="extrapad">true</TD>
    <TH><SMALL>OLE DB</SMALL> Property</TH><TD CLASS="extrapad"><SMALL>SSPROP_INIT_AUTOTRANSLATE</SMALL></TD></TR>
</TABLE>
</P>
<P> A boolean property, which, well I&#39;m foggy on the exact effect. Books Online
 says <SMALL>&quot;OEM/ANSI</SMALL> character conversion&quot;, but I don&#39;t think that is correct. I <I>
 believe</I> this property comes into play for the <B><CODE>char</CODE></B>, <B>
   <CODE>varchar</CODE></B> and <B><CODE>text</CODE></B> data
 types when the client&#39;s <SMALL>ANSI</SMALL> code page does not match the code page of the
 server collation. Anyway, Win32::SqlServer does not set this property, but according to Books Online this property is on by default. </P>

<H3><A NAME="ConnectionString">ConnectionString</A></H3>
<P>
<TABLE BORDER=1 CELLSPACING=0 CELLPADDING=0>
<TR><TH>Data type</TH><TD CLASS="extrapad">string</TD><TH>Default</TH><TD CLASS="extrapad"><CODE>undef</CODE>
</TD><TH><SMALL>OLE DB</SMALL> Property</TH><TD CLASS="extrapad"><SMALL>DBPROP_INIT_PROVIDERSTRING</SMALL></TD></TR>
</TABLE>
</P>
<P>Instead of setting all properties individually, you can set all in one bang
with a connection string, just as they do in other interfaces. If you set this
property, Win32::SqlServer flushes the settings for all other login properties, including
its default values. So, for instance, if you set the <B>ConnectionString</B>
property, but do not include <I>Initial Catalog</I> in the connection string,
the user&#39;s default database will apply, not tempdb. If you then go on to set
other login properties with <A HREF="#setloginproperty"><SPAN CLASS="nowrap">setloginproperty()</SPAN></A>, I believe that that these take
precedence over the connection string.</P>
<P>There is one property you should not include in the connection string, and
   that is the <I>Provider</I> keyword. To set which provider to use you must use the
   Win32::SqlServer property <B><A HREF="#Provider">Provider</A></B>.
</P>
<P>For a full list of available keywords for the connection string, please see
   this <A HREF="http://msdn.microsoft.com/en-us/library/ms130822.aspx">topic in Books Online</A>.</P>

<H3><A NAME="ConnectTimeout">ConnectTimeout</A></H3>
<P>
<TABLE BORDER=1 CELLSPACING=0 CELLPADDING=0>
<TR><TH>Data type</TH><TD CLASS="extrapad">integer</TD><TH>Default</TH><TD CLASS="extrapad">15</TD>
     <TH><SMALL>OLE DB</SMALL> Property</TH><TD CLASS="extrapad"><SMALL>DBPROP_INIT_TIMEOUT</SMALL></TD></TR>
</TABLE>
</P>
<P>How many seconds Win32::SqlServer should wait before
giving up when trying to connect to <SMALL>SQL</SMALL> Server. (This is not the same as the command timeout,
   which you can set with the Win32::SqlServer property <B>
<A HREF="#CommandTimeout">CommandTimeout</A></B>.)</P>

<H3><A NAME="LogpropDatabase">Database</A></H3>
<P>
<TABLE BORDER=1 CELLSPACING=0 CELLPADDING=0>
<TR><TH>Data type</TH><TD CLASS="extrapad">string</TD><TH>Default</TH><TD CLASS="extrapad"><CODE>&quot;tempdb&quot;</CODE>
    </TD><TH><SMALL>OLE DB</SMALL> Property</TH><TD CLASS="extrapad"><SMALL>DBPROP_INIT_CATALOG</SMALL></TD></TR>
</TABLE>
</P>
 <P> Which database to connect to initially. Note that by default Win32::SqlServer sets
   <B>tempdb</B>
    as the initial database. If you want to connect to whichever database that
    is registered as the default in <SMALL>SQL</SMALL> Server, set this property to <CODE>undef</CODE>.</P>

<H3><A NAME="Encrypt">Encrypt</A></H3>
<P>
<TABLE BORDER=1 CELLSPACING=0 CELLPADDING=0>
<TR><TH>Data type</TH><TD CLASS="extrapad">boolean</TD><TH>Default</TH><TD CLASS="extrapad">false</TD>
    <TH><SMALL>OLE DB</SMALL> Property</TH><TD CLASS="extrapad"><SMALL>SSPROP_INIT_ENCRYPT</SMALL></TD></TR>
</TABLE>
</P>
<P>Whether the connection is to be encrypted. Please refer to Books Online for
   further details. </P>

<H3><A NAME="FailoverPartner">FailoverPartner</A></H3>
<P>
<TABLE BORDER=1 CELLSPACING=0 CELLPADDING=0>
<TR><TH>Data type</TH><TD CLASS="extrapad">string</TD><TH>Default</TH><TD CLASS="extrapad"><CODE>undef</CODE></TD>
    <TH><SMALL>OLE DB</SMALL> Property</TH><TD CLASS="extrapad"><SMALL>SSPROP_INIT_FAILOVERPARTNER</SMALL></TD></TR>
</TABLE>
</P>
<P>Failover partner for database mirroring. Please see Books Online for further discussion. This property is unavailable with
   the <SMALL>SQLOLEDB</SMALL> provider and applies only to <SMALL>SQL</SMALL>&nbsp;2005
and later.</P>

<H3><A NAME="FailoverPartnerSPN">FailoverPartnerSPN</A></H3>
<P>
<TABLE BORDER=1 CELLSPACING=0 CELLPADDING=0>
<TR><TH>Data type</TH><TD CLASS="extrapad">string</TD><TH>Default</TH><TD CLASS="extrapad"><CODE>undef</CODE></TD>
    <TH><SMALL>OLE DB</SMALL> Property</TH><TD CLASS="extrapad"><SMALL>SSPROP_INIT_FAILOVERPARTNERSPN</SMALL></TD></TR>
</TABLE>
</P>
<P>The <SMALL>SPN</SMALL> for the failover partner. Please see Books Online for details. This 
property requires the <SMALL>SQLNCLI10</SMALL> provider or later.</P>

<H3><A NAME="Hostname">Hostname</A></H3>
<P>
<TABLE BORDER=1 CELLSPACING=0 CELLPADDING=0>
<TR><TH>Data type</TH><TD CLASS="extrapad">string</TD><TH>Default</TH><TD CLASS="extrapad"><CODE>$ENV{COMPUTERNAME}</CODE>
</TD><TH><SMALL>OLE DB</SMALL> Property</TH><TD CLASS="extrapad"><SMALL>SSPROP_INIT_WSID</SMALL></TD></TR>
</TABLE>
</P>
<P>A string that represents the machine you are connecting from and which
resurfaces in the <SMALL>SQL</SMALL> function <SPAN CLASS="nowrap"><SMALL>HOST_NAME</SMALL>()</SPAN>. </P>

<H3><A NAME="IntegratedSecurity">IntegratedSecurity</A></H3>
<P>
<TABLE BORDER=1 CELLSPACING=0 CELLPADDING=0>
<TR><TH>Data type</TH><TD CLASS="extrapad">string</TD><TH>Default</TH><TD CLASS="extrapad"><CODE>&quot;SSPI&quot;</CODE>
</TD><TH><SMALL>OLE DB</SMALL> Property</TH><TD CLASS="extrapad"><SMALL>DBPROP_AUTH_INTEGRATED</SMALL></TD></TR>
</TABLE>
</P>
<P>Specifies whether Win32::SqlServer should connect with Windows Authentication
and this is the default. As far as I know, &quot;<SMALL>SSPI</SMALL>&quot; is the only
   available value. <A HREF="#setloginproperty"><SPAN CLASS="nowrap">setloginproperty()</SPAN></A> accepts the number 1 as the equivalent to
   &quot;<SMALL>SSPI</SMALL>&quot;. Note that if you set the login
property <B><A HREF="#LogPropUsername">Username</A></B>, Win32::SqlServer automatically
clears <B><A HREF="#IntegratedSecurity">IntegratedSecurity</A></B>. </P>

<H3><A NAME="LogpropLanguage">Language</A></H3>
<P>
<TABLE BORDER=1 CELLSPACING=0 CELLPADDING=0>
<TR><TH>Data type</TH><TD CLASS="extrapad">string</TD><TH>Default</TH><TD CLASS="extrapad"><CODE>undef</CODE></TD>
    <TH><SMALL>OLE DB</SMALL> Property</TH><TD CLASS="extrapad"><SMALL>SSPROP_INIT_CURRENTLANGUAGE</SMALL></TD></TR>
</TABLE>
</P>
<P>A string that represents an <SMALL>SQL</SMALL> Server language. This property has the same
   effect as the <SMALL>SET LANGUAGE</SMALL> command. When you do not set a language, the default language defined
   for the server login applies.</P>

<H3><A NAME="LCID">LCID</A></H3>
<P>
<TABLE BORDER=1 CELLSPACING=0 CELLPADDING=0>
<TR><TH>Data type</TH><TD CLASS="extrapad">integer</TD><TH>Default</TH><TD CLASS="extrapad">
   see below.</TD>
    <TH><SMALL>OLE DB</SMALL> Property</TH><TD CLASS="extrapad"><SMALL>DBPROP_INIT_LCID</SMALL></TD></TR>
</TABLE>
</P>
<P>The locale ID. My interpretation of Books
Online is that it does not have much effect. Nevertheless, Win32::SqlServer sets a default
value by calling the Windows function <I>GetUserDefault<SMALL>LCID</SMALL></I>.</P>
<H3><A NAME="MultiSubnetFailover">MultiSubnetFailover</A></H3>
<P>
<TABLE BORDER=1 CELLSPACING=0 CELLPADDING=0>
<TR><TH>Data type</TH>
<TD CLASS="extrapad">boolean</TD><TH>Default</TH>
<TD CLASS="extrapad">false</TD><TH><SMALL>OLE DB</SMALL> Property</TH><TD CLASS="extrapad"><SMALL>SSPROP_INIT_MULTISUBNETFAILOVER</SMALL></TD></TR>
</TABLE>
</P>
<P>Set this property to a true value when connecting to an availability group. This property is only available with the <SMALL>MSOLEDBSQL</SMALL> provider.</P>
<H3><A NAME="Netlib">Netlib</A></H3>
<P>
<TABLE BORDER=1 CELLSPACING=0 CELLPADDING=0>
<TR><TH>Data type</TH><TD CLASS="extrapad">string</TD><TH>Default</TH><TD CLASS="extrapad"><CODE>undef</CODE>
    </TD><TH><SMALL>OLE DB</SMALL> Property</TH><TD CLASS="extrapad"><SMALL>SSPROP_INIT_NETWORKLIBRARY</SMALL></TD></TR>
</TABLE>
</P>
<P>Which network library to use for the connection. Please refer to Books Online
   for details.</P>

<H3><A NAME="NetworkAddress">NetworkAddress</A></H3>
<P>
<TABLE BORDER=1 CELLSPACING=0 CELLPADDING=0>
<TR><TH>Data type</TH><TD CLASS="extrapad">string</TD><TH>Default</TH><TD CLASS="extrapad"><CODE>undef</CODE>
     </TD><TH><SMALL>OLE DB</SMALL> Property</TH><TD CLASS="extrapad"><SMALL>SSPROP_INIT_NETWORKADDRESS</SMALL></TD></TR>
</TABLE>
</P>
<P>A network address for the server defined by the <B>
<A HREF="#LogPropServer">Server</A></B> property. </P>

<H3><A NAME="OldPassword">OldPassword</A></H3>
<P>
<TABLE BORDER=1 CELLSPACING=0 CELLPADDING=0>
<TR><TH>Data type</TH><TD CLASS="extrapad">string</TD><TH>Default</TH><TD CLASS="extrapad"><CODE>undef</CODE>
    </TD><TH><SMALL>OLE DB</SMALL> Property</TH><TD CLASS="extrapad"><SMALL>SSPROP_AUTH_OLD_PASSWORD</SMALL></TD></TR>
</TABLE>
</P>
<P>This property is only applicable when you use <SMALL>SQL</SMALL> authentication. When set, it
should be the <I>current</I> password for the <SMALL>SQL</SMALL> login specified by the <B>
<A HREF="#LogPropUsername">Username</A></B> login property. The <B>
<A HREF="#LogpropPassword">Password</A></B> property should in this case the hold the <I>new</I>
   password for the <SMALL>SQL</SMALL> login. Thus, you can use this property to change the
   password for an <SMALL>SQL</SMALL> login when connecting.
This property is unavailable with
   the <SMALL>SQLOLEDB</SMALL> provider and applies only to <SMALL>SQL</SMALL>&nbsp;2005
and later.</P>

<H3><A NAME="PacketSize">PacketSize</A></H3>
<P>
<TABLE BORDER=1 CELLSPACING=0 CELLPADDING=0>
<TR><TH>Data type</TH><TD CLASS="extrapad">integer</TD><TH>Default</TH><TD CLASS="extrapad"><CODE>undef</CODE></TD>
    <TH><SMALL>OLE DB</SMALL> Property</TH><TD CLASS="extrapad"><SMALL>SSPROP_INIT_PACKETSIZE</SMALL></TD></TR>
</TABLE>
</P>
<P>A number between 512 and 32767 which sets the network packet size. When
   <CODE>undef</CODE>, the default is taken from the server-side configuration parameter <I>
   network packet size</I>, which you can set with <B>sp_configure</B>.</P>

<H3><A NAME="LogpropPassword">Password</A></H3>
<P>
<TABLE BORDER=1 CELLSPACING=0 CELLPADDING=0>
<TR><TH>Data type</TH><TD CLASS="extrapad">string</TD><TH>Default</TH><TD CLASS="extrapad"><CODE>undef</CODE></TD>
    <TH><SMALL>OLE DB</SMALL> Property</TH><TD CLASS="extrapad"><SMALL>DBPROP_AUTH_PASSWORD</SMALL></TD></TR>
</TABLE>
</P>
<P>This property applies only if you also have specified the <B>
<A HREF="#LogPropUsername">Username</A></B> property. It is the password for
   that <SMALL>SQL</SMALL> login. See also <B><A HREF="#OldPassword">OldPassword</A></B> on how
   to change the password for an <SMALL>SQL</SMALL> login when connecting.</P>

<H3><A NAME="Pooling">Pooling</A></H3>
<P>
<TABLE BORDER=1 CELLSPACING=0 CELLPADDING=0>
<TR><TH>Data type</TH><TD CLASS="extrapad">boolean</TD><TH>Default</TH><TD CLASS="extrapad">true</TD>
    <TH><SMALL>OLE DB</SMALL> Property</TH><TD CLASS="extrapad"><SMALL>DBPROP_INIT_OLEDBSERVICES</SMALL></TD></TR>
</TABLE>
</P>
<P>Whether connection pooling is
enabled. Connection pooling is handled by <SMALL>OLE DB</SMALL>
core services. When connection pooling is in effect, the physical <SMALL>SQL</SMALL> Server connection is not terminated when you call <A HREF="#disconnect"><SPAN CLASS="nowrap">disconnect()</SPAN></A>
   or when the Win32::SqlServer object goes out of scope. Instead, the
   <SMALL>OLE DB</SMALL> provider retains the connection, and if you reconnect with the same login properties, the
connection is likely to be reused. If there is no reconnection for some time,
normally 60 seconds, <SMALL>OLE DB</SMALL> disconnects. (You cannot change this setting through
Win32::SqlServer, as it is a registry setting. Please refer to the <SMALL>MSDN</SMALL> topic <I><A HREF="http://msdn.microsoft.com/en-us/library/windows/desktop/ms713655.aspx">Resource Pooling</A></I>.)</P>
<P>
When this setting is false, the connection is physically disconnected when you call <A HREF="#disconnect"><SPAN CLASS="nowrap">disconnect()</SPAN></A> or when the Win32::SqlServer object goes out of scope.</P>
<P>Pooling permits you to connect and disconnect, for instance by having a local Win32::SqlServer object in each <CODE>sub</CODE> without any overhead.<CODE></CODE> However, if you
  have poor transaction handling, any outstanding transaction on the pooled
  connection is not rolled back until the connection is reused or physically
  disconnected. This can lead to blocking scenarios. Also, be aware that if you
  are using application roles, you <I>cannot</I> use connection pooling on <SMALL>SQL</SMALL>
  2000. On <SMALL>SQL</SMALL> 2005 and later, it is possible, but you need to take some precautions, as
discussed in Books Online.</P>
<P> (Readers well versed <SMALL>in OLE DB</SMALL> may know that <SMALL>DBPROP_INIT_OLEDBSERVICES</SMALL> is in fact a bit mask that controls other <SMALL>OLE DB</SMALL>
    services as well. Currently Win32::SqlServer always turns off these other services.)
</P>
<H3><A NAME="LogpropPrompt">Prompt</A></H3>
<P>
<TABLE BORDER=1 CELLSPACING=0 CELLPADDING=0>
<TR><TH><SPAN CLASS="nowrap">Data type</SPAN></TH><TD CLASS="extrapad">integer</TD>
   <TH>Default</TH><TD CLASS="extrapad"><SMALL>DBPROMPT_NOPROMPT</SMALL>(4)</TD>
   <TH><SPAN CLASS="nowrap"><SMALL>OLE DB</SMALL> Property</SPAN></TH><TD CLASS="extrapad"><SMALL>DBPROP_INIT_PROMPT</SMALL></TD></TR>
</TABLE>
</P>
<P><SMALL>OLE DB</SMALL> can display a small window where the user can
specify login information. This is controlled by <B><A HREF="#LogpropPrompt">Prompt</A>.</B>
   This property can take any of these four different values (Text
from <A HREF="http://msdn.microsoft.com/en-us/library/windows/desktop/ms714342.aspx"><SMALL>MSDN</SMALL></A>):</P>
   <UL>
      <LI><SMALL>DBPROMPT_PROMPT</SMALL> (1) – Always prompt the user for
         initialization information.
      </LI>
      <LI><SMALL>DBPROMPT_COMPLETE</SMALL> (2) – Prompt the user only if more
         information is needed.
      </LI>
      <LI><SMALL>DBPROMPT_COMPLETEREQUIRED</SMALL> (3) – Prompt the user only if
         more information is needed. Do not allow the user to enter optional
         information.
      </LI>
      <LI><SMALL>DBPROMPT_NOPROMPT</SMALL> (4) – Do not prompt the user. </LI>
   </UL>
<P>Win32::SqlServer does not declare these constants for you, so you will have to declare
   them yourself or use the numbers.</P>

<H3><A NAME="LogPropServer">Server</A></H3>
<P>
<TABLE BORDER=1 CELLSPACING=0 CELLPADDING=0>
<TR><TH>Data type</TH><TD CLASS="extrapad">string</TD><TH>Default</TH><TD CLASS="extrapad"><CODE>&quot;(local)&quot;</CODE></TD>
    <TH><SMALL>OLE DB</SMALL> Property</TH><TD CLASS="extrapad"><SMALL>DBPROP_INIT_DATASOURCE</SMALL></TD></TR>
</TABLE>
</P>
<P>Which <SMALL>SQL</SMALL> Server instance to connect to.</P>

<H3><A NAME="ServerSPN">ServerSPN</A></H3>
<P>
<TABLE BORDER=1 CELLSPACING=0 CELLPADDING=0>
<TR><TH>Data type</TH><TD CLASS="extrapad">string</TD><TH>Default</TH><TD CLASS="extrapad">
   <CODE>undef</CODE></TD>
    <TH><SMALL>OLE DB</SMALL> Property</TH><TD CLASS="extrapad">
   <SMALL>SSPROP_INIT_SERVERSPN</SMALL></TD></TR>
</TABLE>
</P>
<P>The <SMALL>SPN</SMALL> for the server you are connecting to. Please see Books Online for 
details. This property is only available with the <SMALL>SQLNCLI10</SMALL> provider or later.</P>

<H3>&nbsp;<A NAME="TrustServerCert">TrustServerCert</A></H3>
<P>
<TABLE BORDER=1 CELLSPACING=0 CELLPADDING=0>
<TR><TH>Data type</TH><TD CLASS="extrapad">boolean</TD><TH>Default</TH><TD CLASS="extrapad">false</TD>
    <TH><SMALL>OLE DB</SMALL> Property</TH><TD CLASS="extrapad"><SMALL>SSPROP_INIT_TRUST_SERVER_CERTIFICATE</SMALL></TD></TR>
</TABLE>
</P>
<P>Whether you trust the server certificate when you use encryption. Please
refer to Books Online for further details. This property is unavailable with
   the <SMALL>SQLOLEDB</SMALL> provider and applies only to <SMALL>SQL</SMALL>&nbsp;2005
and later.</P>

<H3><A NAME="LogPropUsername">Username</A></H3>
<P>
<TABLE BORDER=1 CELLSPACING=0 CELLPADDING=0>
<TR><TH>Data type</TH><TD CLASS="extrapad">string</TD><TH>Default</TH><TD CLASS="extrapad"><CODE>undef</CODE></TD>
    <TH><SMALL>OLE DB</SMALL> Property</TH><TD CLASS="extrapad"><SMALL>DBPROP_AUTH_USERID</SMALL></TD></TR>
</TABLE>
</P>
<P>Specifies that you want to log in with <SMALL>SQL</SMALL> authentication
   <SMALL>with the given username. </SMALL>When you set this property, the login property <B>
<A HREF="#IntegratedSecurity">IntegratedSecurity</A></B> is automatically
   cleared. (Since if both are set, the provider honours integrated security.)
</P>

<H2><A NAME="connect"><SPAN CLASS="nowrap">connect()</SPAN></A></H2>
<P>Connects to <SMALL>SQL</SMALL> Server using the current login properties.</P>
<PRE>$ret = $sqlsrv-&gt;connect()</PRE>
<DL>
   <DT><CODE>$ret</CODE></DT>
   <DD>True if connection succeeded, else false.</DD>
</DL>
<P>It&#39;s an error to call this function, if you are already connected. You
   can use <A HREF="#isconnected"><SPAN CLASS="nowrap">isconnected()</SPAN></A> to check whether you are connected.</P>
<P>If the login to <SMALL>SQL</SMALL> Server as such fails, <A HREF="#connect"><SPAN CLASS="nowrap">connect()</SPAN></A> invokes the <A HREF="#MsgHandler">current
   message handler</A>. If an error occurs when Win32::SqlServer
   calls the <SMALL>OLE DB</SMALL> provider to submit the login properties,
   Win32::SqlServer aborts and
   prints the error message from the <SMALL>OLE DB</SMALL> provider, but this message may be
   <I>very</I> obscure. In this situation, it may help to set the <B>
   <A HREF="#PropsDebug">PropsDebug</A></B> property to get a dump of the
   current login properties.</P>
<H2><A NAME="disconnect"><SPAN CLASS="nowrap">disconnect()</SPAN></A></H2>
<P>Disconnects from <SMALL>SQL</SMALL> Server and frees up any resources allocated for queries.</P>
<PRE>$sqlsrv-&gt;disconnect()</PRE>
<P>Note that if connection pooling is active, the connection to <SMALL>SQL</SMALL> Server is
   not physically closed, only returned to the connection pool. See the <B>
 <A HREF="#Pooling">Pooling</A></B> login property for a further discussion on
   connection pooling.</P>
<P>It&#39;s permitted to call this function, even if you are already disconnected. </P>
<P>If a Win32::SqlServer object goes out of scope, it automatically disconnects from <SMALL>SQL</SMALL> Server.</P>
<H2><A NAME="isconnected"><SPAN CLASS="nowrap">isconnected()</SPAN></A></H2>
<P>Returns whether you are connected to <SMALL>SQL</SMALL> Server or not.</P>
<PRE>$ret = $sqlsrv-&gt;isconnected();</PRE>
<DL>
   <DT><CODE>$ret</CODE></DT>
   <DD>1 if you are currently connected to <SMALL>SQL</SMALL> Server, 0 if you are
   disconnected.</DD>
</DL>
<P>This function returns Win32::SqlServer&#39;s internal connection state. If the physical
   connection somehow was severed &#8211; network error, severe <SMALL>SQL</SMALL> Server
   error &#8211; but Win32::SqlServer has not discovered this yet,
   <A HREF="#isconnected"><SPAN CLASS="nowrap">isconnected()</SPAN></A> returns 1.</P>
<P>Note that if even this function returns 0, the connection could still exist
   in <SMALL>SQL</SMALL> Server, due to <A HREF="#Pooling">connection pooling</A>. </P>

<H1><A NAME="High-level">High-Level Query Functions</A></H1>
<P>The intention is that 99% of the time, you will be running one of
   <A HREF="#sql"><SPAN CLASS="nowrap">sql()</SPAN></A> and <A HREF="#sql_sp"><SPAN CLASS="nowrap">sql_sp()</SPAN></A> to run your queries.
   <A HREF="#sql"><SPAN CLASS="nowrap">sql()</SPAN></A> is for batches of one of more <SMALL>SQL</SMALL> commands while <A HREF="#sql_sp"><SPAN CLASS="nowrap">sql_sp()</SPAN></A>
   is for running one stored procedure (or a scalar user-defined function).
   The two share a common feature: the four parameters <CODE>$colinfostyle</CODE>, <CODE>$rowstyle</CODE>,
   <CODE>$resultstyle</CODE> and <SPAN CLASS="nowrap"><CODE>\@keys</CODE></SPAN> that you use
   to specify how you want the result set(s) from the command batch/stored
   procedure to be structured in Perl. This is described in detail in the
   sections <A HREF="#RowResultStyles">Row Styles and Result Styles</A> and
<A HREF="#colinfostyles">Getting Column Information</A>
   under the topic of <A HREF="#sql"><SPAN CLASS="nowrap">sql()</SPAN></A>. Both functions also accept parameters to the
   command batch/stored procedure, but there is a difference between the
   two:
   <A HREF="#sql"><SPAN CLASS="nowrap">sql()</SPAN></A> requires you to specify the data types, whereas
   <A HREF="#sql_sp"><SPAN CLASS="nowrap">sql_sp()</SPAN></A> retrieves the parameter profile from <SMALL>SQL</SMALL> Server 
or from an internal cache. This chapter also covers
   <A HREF="#sql_one"><SPAN CLASS="nowrap">sql_one()</SPAN></A> which is for queries that should return exactly one row and
   <A HREF="#sql_insert"><SPAN CLASS="nowrap">sql_insert()</SPAN></A> that inserts data into a table from hash. There
is also a special section <A HREF="#TVP">Working with Table Parameters</A>, that
details how to use this feature added in <SMALL>SQL</SMALL> 2008.</P>
<P>The high-level query functions makes use of Perl&#39;s flexible nature, and
   permits you leave out most parameters, even in the middle of the
   parameter list.</P>
<H2><A NAME="sql"><SPAN CLASS="nowrap">sql()</SPAN></A></H2>
<P>Runs a batch of one or more <SMALL>SQL</SMALL> commands. The batch may be parameterised.</P>
<PRE>($|@|%)result = $sqlsrv-&gt;sql($batch
                             [, \@unnamed_parameters] [, \%named_parameters]
                             [, $colinfostyle] [, $rowstyle] [, $resultstyle [, \@keys]]);</PRE>
<H3>Parameters</H3>
<DL>
   <DT><CODE>($|@|%)result</CODE></DT>
   <DD>The result set(s) from <CODE>$batch</CODE>. Depending on the <CODE>
   $rowstyle</CODE> and
   <CODE>$resultstyle</CODE> parameters, this can be an array, a hash or a scalar.
   If the result set(s) come back as an array or a hash, and you receive the
   return value into a scalar, you get a reference to the array/hash. This is
   described more in detail in the section <A HREF="#RowResultStyles">Row Styles and Result Styles</A>
   below.</DD>
   <DT>&nbsp;</DT>
   <DT><CODE>$batch</CODE></DT>
   <DD>A batch of one or more <SMALL>SQL</SMALL> statements. (Keep in mind that
   <SMALL>GO</SMALL>
   is not an <SMALL>SQL</SMALL> command, so don&#39;t include that in your command batch.)</DD>
   <DT>&nbsp;</DT>
   <DT><CODE>\@unnamed_parameters</CODE></DT>
   <DD>A reference to an array with input for unnamed parameters. Unnamed
   parameters appears as <CODE>?</CODE> in <CODE>$batch</CODE>. Each entry in the array is an
   inner array with two or three entries. The first entry is the data type of the
   parameter, the second is the value for the parameter, or a reference to the value if the parameter is an output parameter. The third is used only
     when the data type is <B><CODE>xml, table</CODE></B> or <B><CODE>UDT</CODE></B>, in
     which case it specifies an <SMALL>XML</SMALL> schema collection or the name of the <SMALL> table type or the UDT</SMALL>. Ser
     further the section <A HREF="#parameterspecdetails">Details on the Parameter
   Specification</A>.</DD>
   <DT>&nbsp;</DT>
   <DT><CODE>\%named_parameters</CODE></DT>

   <DD>A reference to a hash with input for named parameters. Named parameters
   appears as <SMALL>T-SQL</SMALL> variables, e.g. <CODE><SPAN CLASS="nowrap">@p1</SPAN></CODE>, in <CODE>$batch</CODE>. The key is the parameter
   name, and you can specify it with or without the leading <CODE>@</CODE>. Each entry in the
   hash is an array as described for the parameter <CODE><SPAN CLASS="nowrap">\@unnamed_parameters</SPAN></CODE>.</DD>
   <DT>&nbsp;</DT>
   <DT><CODE>$colinfostyle</CODE></DT>
   <DD>Specifies if and how you want information about the columns in the
   result set(s). Possible values are <A HREF="#COLINFO_NONE"><SMALL>COLINFO_NONE</SMALL></A> (no information),
   <A HREF="#COLINFO_NAMES"><SMALL>COLINFO_NAMES</SMALL></A> (names only), <A HREF="#COLINFO_POS"><SMALL>COLINFO_POS</SMALL></A> (column numbers only) and
   <A HREF="#COLINFO_FULL"><SMALL>COLINFO_FULL</SMALL></A> (a hash with detailed information about the columns). See the
   section <A HREF="#colinfostyles">Getting Column Information</A> below for
   details. The default is <A HREF="#COLINFO_NONE"><SMALL>COLINFO_NONE</SMALL></A>.</DD>
   <DT>&nbsp;</DT>
   <DT><CODE>$rowstyle</CODE></DT>

   <DD>Specifies how each row in the result is to be represented. Possible
   values are <A HREF="#HASH"><SMALL>HASH</SMALL></A> (each row is a hash keyed by column name), <A HREF="#LIST"><SMALL>LIST</SMALL></A> (each
   row is an array) and <A HREF="#SCALAR"><SMALL>SCALAR</SMALL></A> (each row is a scalar value). See the section
   <A HREF="#RowResultStyles">Row Styles and Result Styles</A> below for
   details. Default is <A HREF="#HASH"><SMALL>HASH</SMALL></A>.</DD>
   <DT>&nbsp;</DT>
   <DT><CODE>$resultstyle</CODE></DT>
   <DD>Specifies how the result sets are to be structured. Possible values are
   <A HREF="#MULTISET"><SMALL>MULTISET</SMALL></A> (an array of result sets),
   <A HREF="#MULTISET_RC"><SMALL>MULTISET_RC</SMALL></A> (an array of result sets and row counts for action statements),
   <A HREF="#SINGLESET"><SMALL>SINGLESET</SMALL></A> (an array of rows), <A HREF="#SINGLEROW"><SMALL>SINGLEROW</SMALL></A>
   (a single row according to <CODE>$rowstyle</CODE>), <A HREF="#KEYED"><SMALL>KEYED</SMALL></A> (a hash, keyed by
   the data in the result set), <A HREF="#NORESULT"><SMALL>NORESULT</SMALL></A> (no result set returned) or a reference
   to a <A HREF="#Callbacks">callback</A> routine that is to be called for each row. See the section
   <A HREF="#RowResultStyles">Row Styles and Result Styles</A> below for
   details. Default is <A HREF="#SINGLESET"><SMALL>SINGLESET</SMALL></A>.</DD>
   <DT>&nbsp;</DT>
   <DT><CODE>\@keys</CODE></DT>
   <DD>This parameter is only applicable when <CODE>$resultstyle</CODE> is
   <A HREF="#KEYED"><SMALL>KEYED</SMALL></A>, in which case it&#39;s mandatory. It specifies which column(s) in the
   result set to use for keys.</DD>
</DL>
<H3>Passing Parameters to SQL Batches</H3>
<P>This section starts with two subsections on guidelines, before going into
   the reference stuff. If you are in a hurry, you may want to jump directly to
 <A HREF="#unnamednamed">Unnamed and Named Parameters</A>, or even
 <A HREF="#parameterspecdetails">Details on the Parameter Specification</A>.</P>
<H4><A NAME="whyparameter">Why Parameterise SQL Commands at All?</A></H4>
<P>There are three reasons 1) simplicity, 2) security and 3) performance.</P>
<P>The first two reasons are actually two angles of the same problem. Say that
   you have a script that permits a user to enter a part of a name and the
   script looks up matching rows. A simple-minded version would perhaps be:</P>
<PRE>$batch = &lt;&lt;SQLEND;
    SELECT CompanyName
    FROM   Customers
    WHERE  CompanyName LIKE &#39;$userentry%&#39;
SQLEND
$result = $sqlsrv-&gt;sql($batch, Win32::SqlServer::SCALAR);</PRE>
<P>Quick testing indicates that this appears to work. But then a poor user enters <I>Let&#39;s</I>
whereupon the query
   dies with a syntax error because of the odd number of single quotes, instead
   of returning <I>Let&#39;s stop N shop</I>. That was
   the poor and innocent user. Next user is outright malicious, and he enters:</P>
<PRE>La&#39;; DROP TABLE Customers --</PRE>
<P>The resulting batch to sent to <SMALL>SQL</SMALL> Server
   becomes:</P>
<PRE>SELECT CompanyName
FROM   Customers
WHERE  CompanyName LIKE &#39;La&#39;; DROP TABLE Customers -- %&#39;</PRE>
<P>And if this script runs with enough privileges, the table goes away. This
   technique is known as <SMALL>SQL</SMALL> injection, and is a common line of attack on web
   sites that passes user input to a <SMALL>DBMS</SMALL> (could be any; not just <SMALL>SQL</SMALL>
   Server).</P>
<P>As you see, what all the fuzz is about is handling string delimiters in the input data.
   You could do something like <CODE>$userentry =~ s/&#39;/&#39;&#39;/g</CODE>,
   on your own or call <A HREF="#sql_string"><SPAN CLASS="nowrap">sql_string()</SPAN></A> for
   the task. But if you
   have several string parameters your code gets bulky, not the least if you
   need to use <CODE>$userentry</CODE> later in it&#39;s original form. This is
   where parameterised commands come to the rescue:</P>
<PRE>$batch = &lt;&lt;SQLEND;
   SELECT CompanyName
   FROM   Customers
   WHERE  CompanyName LIKE ? + &#39;%&#39;
SQLEND
$result = $sqlsrv-&gt;sql($batch, [[&#39;nvarchar&#39;, $userentry]],
                       Win32::SqlServer::SCALAR);
</PRE>
<P>This will eventually result in a remote procedure call, where <CODE>
   $userentry</CODE> will be a parameter and it will not matter if there are any
   single quotes in it. Thus, there is no way an intruder can get in here, and
   there is no risk a user gets a strange error with some data. </P>
<P>Another slant of this is datetime values. If you include the string
&quot;2006-08-21&quot; in a <SMALL>T-SQL</SMALL> batch, <SMALL>SQL</SMALL> Server may take it as just that if the
<SMALL>DATEFORMAT</SMALL> setting is <B>mdy</B> or <B>ymd</B>, but if the setting is <B>dmy</B>,
<SMALL>SQL</SMALL> Server will consider it an error. By passing datetime values as parameters,
you let Win32::SqlServer do the interpretation with better odds for a correct
interpretation.</P>
<P>The third reason, as I said is performance. When <SMALL>SQL</SMALL> Server receives the 
query text, it hashes the text and looks up the hash in the plan cache and in case of a match an existing plan is reused. If you 
  interpolate parameter values into the query string, the hash value will be 
different and <SMALL>SQL</SMALL> Server will have to compile the query every time. A parameterised query is constant, and thus the execution plan will be reused which can mean a huge performance gain for queries that are submitted with high frequency.</P>
<H4><A NAME="whennotparameter">When You Should Not Parameterise</A></H4>
<P>Yes, there are a few cases where you should not use parameterised statements.
   An unparameterised command batch is passed to <SMALL>SQL</SMALL> Server as-is, a batch in
   the top scope of the connection. (A scope in
   <SMALL>T-SQL</SMALL> is a stored procedure, a trigger, a function or a batch of dynamic <SMALL>SQL</SMALL>;
   all very reminiscent of Perl.) A parameterised batch, on the other hand, is executed through
   <B>
   <A HREF="http://www.sommarskog.se/dynamic_sql.html">sp_executesql</A></B>.
   This creates a new scope, which means that if your command batch creates a
   temp table, the temp table will be dropped when the batch exits. Thus, if you
   create a temp table what you want to reuse in later command batches, you must
   use an unparameterised command batch. The same issue applies to <SMALL>SET</SMALL>
   commands: the effect of a <SMALL>SET</SMALL> command is reverted when the
   scope exits, so if you want, say, <SMALL>SET NOCOUNT ON</SMALL> to have
   effect for the rest of connection, you should issue it in an unparameterised
   batch.</P>
<P>There is one more case worth mentioning. You cannot parameterise everything.
   This does not fly:</P>
<PRE>$result = $sqlsrv-&gt;sql(&quot;SELECT * FROM ?&quot;, [[&#39;nvarchar&#39;, &#39;MyTable&#39;]]):</PRE>
<P>This results in a syntax error on <SMALL>SQL&nbsp;</SMALL>7 and
   earlier. On <SMALL>SQL</SMALL>&nbsp;2000 and later, you are told
   that <CODE><SPAN CLASS="nowrap">@P1</SPAN></CODE> is not declared. This is because you can only use parameters where variables are permitted in the <SMALL>T-SQL</SMALL>
   syntax, and <SMALL>T-SQL</SMALL> does not permit you to use a variable for a table
   name. (In fact that would be a table-valued parameter, but then you need to
specify the parameter differently.)</P>
<H4><A NAME="unnamednamed">Unnamed and Named Parameters</A></H4>
<P>There are two ways to specify a parameter in a command batch: by using <CODE>?</CODE>
   as
   a parameter placeholders and by using a standard <SMALL>
<SPAN CLASS="nowrap">T-SQL</SPAN></SMALL> parameter name starting with
   <CODE>@</CODE>. I refer to the former as unnamed parameters, and the latter I
call
   named parameters.</P>
<P>Win32::SqlServer expands the <CODE>?</CODE> to <CODE><SPAN CLASS="nowrap">@P1</SPAN></CODE>, <CODE><SPAN CLASS="nowrap">@P2</SPAN></CODE>, <CODE><SPAN CLASS="nowrap">@P3</SPAN></CODE> etc.
   However, <CODE>?</CODE>
   in string literals, quoted names and comments are not expanded. Here is a
   contrived example:</P>
<PRE>SELECT ?, &#39;?&#39; AS x FROM [Questions?] WHERE col = ? -- eh?</PRE>
<P>This command batch is expanded to:</P>
<PRE>SELECT @P1, &#39;?&#39; AS x FROM [Questions?] WHERE col = @P2 -- eh?</PRE>
<P>The parameter <CODE><SPAN CLASS="nowrap">
   \@unnamed_parameters</SPAN></CODE>
   is really just a shortcut for entries in <SPAN CLASS="nowrap"><CODE>\%named_parameters</CODE></SPAN>
   where the keys are <CODE><SPAN CLASS="nowrap">@P1</SPAN></CODE>, <CODE><SPAN CLASS="nowrap">@P2</SPAN></CODE>
   etc. From this follows, that it&#39;s perfectly possible to mix parameter
   placeholders and named parameters in a command batch. </P>
<P>Parameter placeholders are convenient for single occurrences in short batches,
   but if you need to refer to the same parameter in the same command batch,
   named parameters are easier to use.</P>
<PRE>SELECT col1, col2 FROM tbl WHERE last_name = @name OR first_name = @name</PRE>
<P>Had you used <CODE><CODE>?</CODE></CODE> here, you would in fact have had two
   parameters and not one. Named parameters are also more palatable when you have very many parameters. That <CODE>?</CODE> over
   there, is that
   <CODE><SPAN CLASS="nowrap">@P5</SPAN></CODE> or <CODE><SPAN CLASS="nowrap">@P6</SPAN></CODE>? </P>
<P>When you construct <CODE><SPAN CLASS="nowrap">%named_parameters</SPAN></CODE>, you can leave
   out the <CODE>@</CODE> from the parameter names; Win32::SqlServer will add these. This
   saves you some typing. Compare:</P>
<PRE>{&#39;@myparam&#39; =&gt; [&#39;nchar&#39;, $myvalue]}</PRE>
<P>with</P>
<PRE>{myparam =&gt; [&#39;nchar&#39;, $myvalue]}</PRE>
<P><SPAN CLASS="remark">(Win32::SqlServer could have left it to the OLE DB provider to expand the <CODE>
   ?</CODE>, but for two reasons Win32::SqlServer expands ? itself : 1) to support named
   parameters. 2) The error messages from the OLE DB provider when
   you have errors with the parameters range from the vague and imprecise
   to the completely opaque and impenetrable ones. Win32::SqlServer&#39;s error messages are
   hopefully more informative.)</SPAN></P>
<H4><A NAME="parameterspecdetails">Details on the Parameter Specification</A></H4>
<P>An entry in <CODE><SPAN CLASS="nowrap">\@unnamed_parameters</SPAN></CODE> and <CODE>
   <SPAN CLASS="nowrap">\%named_parameters</SPAN></CODE> can be either a scalar value or a short
   array with two or three elements. If the entry is a scalar value, this is
   the value for the parameter. But this is only meaningful in one case: you
   want to pass <CODE>undef</CODE> (that is <SMALL>NULL</SMALL>)
   for the parameter. If you supply any other value, Win32::SqlServer applies a default data type of <CODE>
   <B>varchar</B></CODE> and at the same time issues a warning through the <A HREF="#MsgHandler">current message handler</A>
   if Perl warnings are enabled.</P>
<P>From this follows that in the normal case you will need to pass the short arrays. Here are the entries.</P>
<DL>
   <DT><B>Index 0 – data type</B></DT>
   <DD>The data type for the parameter. This can be a system type or a user-defined type. When using a system type, you must use the name as it 
   appears in sys.types; you cannot use the data-type synonyms recognised by <SMALL>SQL</SMALL> 
   Server.&nbsp;That is, you must use <CODE><B>int</B></CODE>, <CODE><B>char</B></CODE> and not <CODE><B>integer</B></CODE>, <CODE><B>character</B></CODE> etc. There is one  exception: you can use <B><CODE>rowversion</CODE></B> for <B><CODE>timestamp</CODE></B>. 
     When using a system type, the name is always case-insensitive, that is <CODE> <B>INT</B></CODE> for <B><CODE>int</CODE></B> is accepted. Regarding 
     user-defined types, see below.</DD>
   <DT>&nbsp;</DT>
   <DT><B>Index 1 – the value + input/output</B></DT>
   <DD>The value for the parameter and whether the parameter is an output 
   parameter or not. To specify that a parameter is an output parameter, pass a 
   reference to a scalar (or a <A HREF="#DATETIME_HASH">datetime hash</A>). The 
   input value for the output parameter is the value in the referenced scalar. 
   Anything else than a reference to a scalar or a hash, is an input-only 
   parameter.</DD>
   <DT>&nbsp;</DT>
   <DT><B>Index 2 – extra type info</B></DT>
   <DD>Applies only if the data type is <B><CODE>xml</CODE></B>, <B><CODE>UDT</CODE></B>
   or <B><CODE>table</CODE></B>.
   See further under these data types below.</DD>
</DL>
<P>Here are remarks for specific data types that may require extra information
   beside the type name.</P>
<DL>
   <DT><B><CODE>varchar</CODE>, <CODE>
   nvarchar</CODE>, <CODE>varbinary</CODE></B></DT>
   <DD>You can enter a complete specification, e.g. <B><CODE><SPAN CLASS="nowrap">varchar(20)</SPAN></CODE></B>,
   or just the type name, e.g. <B><CODE>varchar</CODE></B>. In the latter case,
   Win32::SqlServer applies a default which is equal to the maximum length for
   the data type and the <SMALL>SQL</SMALL> Server version, that is
   8000 for <B><CODE>varchar</CODE></B> and <B><CODE>varbinary</CODE></B>, and 4000 for <B><CODE>nvarchar</CODE></B>. If you are on
   <SMALL>SQL</SMALL> 2005 or later, and the value exceeds the
   max length for the type, Win32::SqlServer will apply <B><SPAN CLASS="nowrap"><CODE>MAX</CODE></SPAN></B>.</DD>
<DT>&nbsp;</DT>
   <DT><B><CODE>char</CODE>, <CODE>nchar</CODE>,&nbsp; <CODE>binary</CODE></B></DT>
   <DD>As with <CODE><B>varchar</B></CODE> etc, you can enter a complete specification, e.g. <B>
   <CODE><SPAN CLASS="nowrap">char(20)</SPAN></CODE></B>,
   or just the type name, e.g. <B><CODE>char</CODE></B>. In difference to the
   variable-length types, Win32::SqlServer will use the actual length of the string as the
   default, as using the max length for the type could yield unexpected
   behaviour. However, this has the distinct disadvantage that calls to the
   same query with parameters of different length will yield different cache
   entries (as the parameter list is part of the cache entry). For this reason,
   leaving out the length with fixed-length string and binary types is
   deprecated, and Win32::SqlServer will emit a warning if warnings are enabled
   when this happens.</DD>
<DT>&nbsp;</DT>
   <DT><B><CODE>decimal</CODE></B>, <B><CODE>numeric</CODE></B></DT>
   <DD>If you leave out precision and/or scale, Win32::SqlServer will apply the defaults
   18 and 0, respectively and at the same time pass a warning through the
   <A HREF="#MsgHandler">current message handler</A> unless the value is <CODE>undef</CODE>. That
   is, best practice is to always supply precision and scale.</DD>
   <DT>&nbsp;</DT>
   <DT><B>User-defined types</B></DT>
   <DD>You can specify a user-defined type using one-, two- or three-part notation. 
   The type can be a plain alias type, a <SMALL>CLR UDT</SMALL> or a table type.
     <P>If any component includes a special character such as space or period, you 
   must quote the name with brackets (<CODE>[]</CODE>) or double quotes (<CODE>&quot;&quot;</CODE>) 
   according to the same rules as in <SMALL>SQL</SMALL> Server.

Here are some examples:</P>
   <PRE>[&#39;MyDatabase.MySchema.YourType&#39;, $value]
[&#39;[My Database].MySchema.[Your Type]&#39;, $value]
[&#39;[This-Type]&#39;, $value]
[&#39;&quot;This.Type&quot;&#39;, $value]</PRE>
   Win32::SqlServer looks up the definition in the system catalog, and thus 
   the case-sensitivity is the same as in the system catalog.&nbsp;That is, any 
   database portion follows the server collation, and the name 
     and schema portions follow the database collation, unless you have a 
   contained database on <SMALL>SQL</SMALL> 2012 where all metadata is case-insensitive. </DD>
   <DD>
     <P>Win32::SqlServer caches the type definitions in the object property <B>
     <A HREF="#usertypes">usertypes</A></B> which is a hash, keyed by the type string exactly as you entered it. That is, if you use both <B>mytype</B> and <B>dbo.mytype</B> 
       for the same type, that will be two lookups in the system catalog, and two 
       entries in <B><A HREF="#usertypes">usertypes</A></B>. Note that Win32::SqlServer never clears this 
       cache.&nbsp;That is, if you first connect to one database where <B>mytype</B> is 
       defined as <B><CODE>varchar(5)</CODE></B>, and with the same 
       Win32::SqlServer object then connects to another database where <B>mytype</B> is defined as <B><CODE>bigint</CODE></B>, 
     Win32::SqlServer will still use the definition <B><CODE>varchar(5)</CODE></B>. The only permissible action with <B><A HREF="#usertypes">usertypes</A></B> is to delete an entry; the content is strictly off-limits.&nbsp; </P>
     <P>On <SMALL>SQL</SMALL> 2000 and earlier, the only permitted schema is <B>dbo</B>, since 
     user-defined types were not schema-bound in these old versions.</P>
   </DD>
   <DT><B><CODE>xml</CODE></B></DT>
   <DD>For <B><CODE>xml</CODE></B>, you can specify an <SMALL>XML</SMALL> schema collection.
   You can do this in two ways:  in parentheses after xml, or in the third 
   entry (that is, index = 2, &quot;typeinfo&quot;) in the parameter array. You must use 
   the latter method, if the name includes&nbsp;parentheses. The name can be a one-, 
   two- or three-part name. Thus, all these are fine:
   <PRE>[&#39;xml&#39;, $myxmldoc]                         # Untyped xml.
[&#39;xml(my_schema_collection)&#39;, $value)]     # Typed xml.
[&#39;xml&#39;, $myxmldoc, &#39;my_schema_collection&#39;] # Equvivalent to the previous.
[&#39;xml&#39;, $mydoc, &#39;[my-schema-collection]&#39;]  # Must quote this name.
[&#39;xml(&quot;My Database&quot;.&quot;That Schema&quot;.&quot;My.Collection&quot;)&#39;, $mydoc]  # Ditto.</PRE>
   </DD>
   <DT>&nbsp;</DT>
   <DT><B>CLR UDTs</B></DT>
   <DD>The simplest way to specify a <SMALL>CLR</SMALL> user-defined type is to use the type 
   name directly as discussed under <I>User-defined types </I>above. In 
   compatibility with older versions of Win32::SqlServer, you can also specify
   <B><CODE>UDT</CODE></B> (must be upper case) and then specify the name of the type in the 
   same way as you specify schema collections for <CODE><B>xml</B></CODE>. That is, either  in parentheses 
   after <B><CODE>UDT</CODE></B>, or in the typeinfo entry in the parameter array.</DD>
   <DD></DD>
   <DT>&nbsp;</DT>
   <DT><B>Table-valued parameters</B></DT>
   <DD>Specify a table type by passing the name, in one- or two-part notation; 
   for table types you cannot specify a database component. (Because lack of 
   support in <SMALL>SQL</SMALL> Server.) In compatibility with older versions of 
   Win32::SqlServer, you can also use <B><CODE>table</CODE></B> as the type 
   name, and specify the name of the type in parentheses after <CODE><B>table</B></CODE> or use the 
   third entry in the parameter array. For details on how to pass the table data, see the section <A HREF="#TVP">Working with Table-Parameters</A>.</DD>
</DL>
<H4>Examples Anyone?</H4>
<P>By now, I can hear the reader screaming for example of all this mess. OK, so
   I&#39;m lazy and point you to the <A HREF="#quickexamples">Quick Examples</A>
   earlier in the document. One conclusion you can draw from the examples is
   that it&#39;s perfectly normal to use anonymous arrays and hashes to pass the
   parameter information.</P>
<H3><A NAME="RowResultStyles">Row Styles and Result Styles</A></H3>
<P>The parameters <CODE>$colinfostyle</CODE>, <CODE>$rowstyle</CODE>, <CODE>$resultstyle</CODE> and <CODE>
   <SPAN CLASS="nowrap">\@keys</SPAN></CODE> are all about shaping the result set(s) into the fashion you
   want to digest the data from Perl. The styles are denoted by constants that
   are not imported by default. You can refer to them with the long name, for instance
 <SPAN CLASS="nowrap"> <CODE>
   Win32::SqlServer::HASH</CODE></SPAN>. You can also import them when you say <CODE>use
   Win32::SqlServer</CODE>, either by explicit name or by using the appropriate
 <A HREF="#EXPORTTAGS">export tag</A>.</P>
<P>Note that while the syntax graph for the call displays <CODE>$colinfostyle</CODE>, <CODE>$rowstyle</CODE>
and <CODE>$resultstyle</CODE> in that order, you can specify the parameters in any order, and
if you only need to specify the result style, you do not need to
use <CODE>undef</CODE> as placeholders for the others. The only requirement is that if you
specify <CODE><SPAN CLASS="nowrap">\@keys</SPAN></CODE>, it must be the last parameter.</P>
<P>And while <CODE>$colinfostyle</CODE> is listed as the first of these four parameters, I
will save it to a later section to describe it. In this section, all
explanations of where you find a certain piece of data assumes the default
colinfo style, <A HREF="#COLINFO_NONE"><SMALL>COLINFO_NONE</SMALL></A>.</P>
<P>The row-style constants are fairly easy to get a grip of, so we start with
   these. They describe how a single row is represented.</P>
<DL>
   <DT><B><A NAME="HASH">HASH</A></B> (the default)</DT>
   <DD>Each row appears as a hash, keyed by column name. Win32::SqlServer names 
   nameless columns as <I>Col&nbsp;1</I>, <I>Col&nbsp;2</I> etc. If the same column
   name appears more than once in the result set, you will get a warning if
   Perl warnings are enabled.</DD>
   <DT>&nbsp;</DT>
   <DT><B><A NAME="LIST">LIST</A></B></DT>
   <DD>This gives you an array with the columns appearing in the order as they
   appear in the query, with the first column at index 0.</DD>
   <DT>&nbsp;</DT>
   <DT><B><A NAME="SCALAR">SCALAR</A></B></DT>
   <DD>Each row is returned as a scalar value. As you may guess, <A HREF="#SCALAR"><SMALL>SCALAR</SMALL></A> is
   intended for one-column result sets. But if result set has more than one
   column, you get one string for the entire row with the column values are separated by
   the global Win32::SqlServer variable, <CODE><SPAN CLASS="nowrap">$Win32::SqlServer::SQLSEP</SPAN></CODE>.
   The default value for this variable is <CODE><SPAN CLASS="nowrap">\022</SPAN></CODE>, 
   a control character. Note that if you change it, this affects all
   Win32::SqlServer objects.
   </DD>
</DL>
<P><B>Note</B>: above when I talk about &quot;all columns&quot;, this is really &quot;all
   non-key columns&quot; in the case the result style is <A HREF="#KEYED"><SMALL>KEYED</SMALL></A>.</P>
<P>The result styles are more to the number, and may also be more bewildering
   at first sight. They describe how the result set(s) of your batch are
structured.</P>
<DL>
   <DT><B><A NAME="SINGLESET">SINGLESET</A></B> (the default)</DT>
   <DD>The return value is an array of rows, or – if you receive the return
   value as a scalar – a reference to an array of rows. Each array entry
   is a reference to a hash, a reference to an array or a scalar value depending
   on the value of <CODE>$rowstyle</CODE>. The order of the rows is the same as
   the order served by <SMALL>SQL</SMALL> Server. (Keep in mind that if you want a certain
   order, you must use <SMALL>ORDER BY</SMALL>, else <SMALL>SQL</SMALL> Server is free to use
   any order.)
   <P><A HREF="#SINGLESET"><SMALL>SINGLESET</SMALL></A> is intended for the
      common case when a command batch returns only one result set. However, if the command batch returns several result sets,
   they are all included in the array, and it&#39;s up to you to find the boundaries
   between them.</P>
   <P>Say that you have this command call to <A HREF="#sql"><SPAN CLASS="nowrap">sql()</SPAN></A>:</P>
<PRE>@result = $sqlsrv-&gt;sql(&lt;&lt;SQLEND, {orderid =&gt; [&#39;int&#39;, $orderid]});
   SELECT OrderDate, CustomerID, EmployeeID, ShippedDate
   FROM   Orders
   WHERE  OrderID = \@orderid
   SELECT ProductID, UnitPrice, Quantity, Discount
   FROM   [Order Details]
   WHERE  OrderID = \@orderid
   ORDER  BY ProductID
SQLEND</PRE>
   <P>To refer to the customer ID, you would say <CODE><SPAN CLASS="nowrap">$result[0]{CustomerID}</SPAN></CODE>.
   To refer to the Product IDs, you would say <CODE><SPAN CLASS="nowrap">$result[$i]{ProductID}</SPAN></CODE>
      where <CODE>$i</CODE> starts at 1 and goes to <CODE><SPAN CLASS="nowrap">$#result</SPAN></CODE>.</P>
   <P>If you instead say:   </P>
<PRE>$result = $sqlsrv-&gt;sql(&lt;&lt;SQLEND, ...</PRE>
   <P>you refer to the customer
   ID as <CODE><SPAN CLASS="nowrap">$$result[0]{CustomerID}</SPAN></CODE>, as you now get a reference to
   an array.</P>
   <P>If we change the row style to <A HREF="#LIST"><SMALL>LIST</SMALL></A>, the customer ID is now found at <SPAN CLASS="nowrap"><CODE>$result[0][1]</CODE></SPAN>,
      and the ProductIDs at <CODE><SPAN CLASS="nowrap">$result[$i]</SPAN>[0]</CODE> where <CODE>
      $i</CODE> is as above. (Or <CODE><SPAN CLASS="nowrap">$$result[0][1]</SPAN></CODE> and
      <CODE><SPAN CLASS="nowrap">$$result[$i][0]</SPAN></CODE>, if we receive the return value
      as <CODE>$result = </CODE><SPAN CLASS="nowrap"><CODE>$sqlsrv-&gt;sql(...</CODE>)</SPAN></P></DD>

   <DT><B><A NAME="MULTISET">MULTISET</A></B></DT>
   <DD>You get an array of a result sets, or – if you receive the return value
   as a scalar – a reference to an array of result sets. Each array entry
   is a reference to an array of rows. Note that empty result sets will be
   retained and appear as empty arrays. Using the same example as for <A HREF="#SINGLESET"><SMALL>SINGLESET</SMALL></A>
   above, but throwing in a result style of <A HREF="#MULTISET"><SMALL>MULTISET</SMALL></A>, the customer ID is now at <CODE><SPAN CLASS="nowrap">
   $result[0][0]{CustomerID}</SPAN></CODE>, or <CODE>
   <SPAN CLASS="nowrap">$$result[0][0]{CustomerID}</SPAN></CODE> when receiving the result as a
   reference to an array. The ProductID is at <CODE><SPAN CLASS="nowrap">
   $result[1][$i]{ProductID}</SPAN></CODE> where <CODE>$i</CODE> now goes from 0 to
   <CODE><SPAN CLASS="nowrap">$#{$result[1]}</SPAN></CODE>.
   <P><SPAN CLASS="remark">(If you as a reader feel overwhelmed by all these combinations of
      $,
      brackets and braces, you have my sympathy. However, I am not going into
      details to explain what all that comes from, as this is a reference for a
      Perl module, not on text on Perl itself. I can recommend thorough study of
      chapter 4 of the second edition of the Camel book or similar material, if
      you are not acquainted with arrays of arrays, hashes of hashes etc.)</SPAN></P></DD>

   <DT><A NAME="MULTISET_RC"><B>MULTISET_RC</B></A></DT>
   <DD>This is very similar to <A HREF="#MULTISET"><SMALL>MULTISET</SMALL></A>. The one difference is what happens
   with <SMALL><SPAN CLASS="nowrap">T-SQL</SPAN></SMALL> statements that do not return a result set, but merely produce a row
   count. With <A HREF="#MULTISET"><SMALL>MULTISET</SMALL></A> you get an empty array, with <A HREF="#MULTISET_RC"><SMALL>MULTISET_RC</SMALL></A> you get the
   row count as a scalar value (and not as an element in an nested array). Say that
   you have:

   <PRE>@result = $sqlsrv(&lt;&lt;SQLEND, MULTISET_RC);
    INSERT #temp (colA, colB)
        SELECT thiscol, thatcol FROM sometable  -- Inserts 27 rows.
    SELECT colA, colB FROM #temp
SQLEND</PRE>
<P>At <CODE>$result[0]</CODE> you will find the number 27. At <CODE>$result[1]</CODE>,
you will find a reference to an array with 27 entries, and you could refer to
<CODE>colA</CODE> in the 13th row as <CODE>$result[1][12]{&#39;colA&#39;}</CODE>.</P>
<P><SMALL>SQL</SMALL> Server returns such row counts for <SMALL>INSERT, UPDATE</SMALL> and <SMALL>DELETE</SMALL> statements,
as well as a few more. For <SMALL>PRINT</SMALL> and <SMALL>RAISERROR</SMALL> you also appear to get a row count
that is -1. Row counts are not generated when the setting <SMALL>SET NOCOUNT ON</SMALL> is in
effect. The normal use for <A HREF="#MULTISET_RC"><SMALL>MULTISET_RC</SMALL></A> would be a batch which only performs
<SMALL>INSERT/UPDATE/DELETE</SMALL> operations, and you like to know the number of affected
rows.</P>
<P>Note that if a <SMALL>SELECT</SMALL> query returns an empty result, this will appear as an
empty array also with <A HREF="#MULTISET_RC"><SMALL>MULTISET_RC</SMALL></A>.</P>
   </DD>

   <DT><B><A NAME="SINGLEROW">SINGLEROW</A></B></DT>
   <DD>The return value is supposed to be a single row. If you specify <A HREF="#HASH"><SMALL>HASH</SMALL></A>
   for <CODE>$rowstyle</CODE>, the return value is thus a hash keyed by column
   names, or – if you
   receive the return value as a scalar – a reference to a hash. If <CODE>$rowstyle</CODE> is <A HREF="#LIST"><SMALL>LIST</SMALL></A>, you get an
   array, or a reference to an array. And if <CODE>$rowstyle</CODE> is <A HREF="#SCALAR"><SMALL>SCALAR</SMALL></A> you
   get the scalar value (but not a reference to it!). Would the command batch
   return more than one row, Win32::SqlServer just keeps on adding the data and it may or
   may not make sense. (There is also <A HREF="#sql_one"><SPAN CLASS="nowrap">sql_one()</SPAN></A>
   that returns exactly one row.)
   <P>
   We modify the example above somewhat:</P>
<PRE>$batch = &lt;&lt;SQLEND;
   SELECT OrderDate, CustomerID, EmployeeID, ShippedDate
   FROM   Orders
   WHERE  OrderID = \@orderid
SQLEND
%result = $sqlsrv-&gt;sql($batch, {orderid =&gt; [&#39;int&#39;, $orderid]},
                       SINGLEROW);</PRE>The customer ID is at <SPAN CLASS="nowrap"> <CODE>$result{CustomerID}</CODE>.</SPAN> When getting the result into <CODE>$result</CODE>
   we find it at <CODE><SPAN CLASS="nowrap">
   $$result{CustomerID}</SPAN></CODE>. With row style <A HREF="#LIST"><SMALL>LIST</SMALL></A>, you
   would say:
<PRE>$batch = &lt;&lt;SQLEND;
   SELECT OrderDate, CustomerID, EmployeeID, ShippedDate
   FROM   Orders
   WHERE  OrderID = \@orderid
SQLEND
@result = $sqlsrv-&gt;sql($batch, {orderid =&gt; [&#39;int&#39;, $orderid]},
                       LIST, SINGLEROW);</PRE>
   You refer to the CustomerID as <CODE><SPAN CLASS="nowrap">$result[1]</SPAN></CODE> or <CODE><SPAN CLASS="nowrap">$$result[1]</SPAN></CODE>
   in the reference case. And with <A HREF="#SCALAR"><SMALL>SCALAR</SMALL></A>? Here is an example:
<PRE>$batch = &lt;&lt;SQLEND;
   SELECT COUNT(*) FROM [Order Details] WHERE OrderID = \@orderid
SQLEND
$count = $sqlsrv-&gt;sql($batch, {orderid =&gt; [&#39;int&#39;, $orderid]},
                      SCALAR, SINGLEROW);</PRE>The reader may be appalled by the fact that this even looks simple and
   understandable.
   </DD>
   <DT>&nbsp;</DT>
   <DT><B><A NAME="KEYED">KEYED</A></B></DT>
   <DD>The return value when you use <A HREF="#KEYED"><SMALL>KEYED</SMALL></A> is a hash, or – if you receive the
   return value as a scalar – a reference to a hash. This hash is keyed by
   the <I>data</I> in the result set. The value of each hash is the non-key
   rows, and they appear as a reference to a hash, a reference to an array or as
   scalar value depending on <CODE>$rowstyle</CODE>.
   <P>
   When you use <A HREF="#KEYED"><SMALL>KEYED</SMALL></A>, you must specify <CODE><SPAN CLASS="nowrap">\@keys</SPAN></CODE> to
   specify the keys in the result set. For the <A HREF="#HASH"><SMALL>HASH</SMALL></A> row style you refer to them by column
   name, for <A HREF="#LIST"><SMALL>LIST</SMALL></A> and <A HREF="#SCALAR"><SMALL>SCALAR</SMALL></A>, you refer to them by column number, with the first
   column at number 1. Here is an example:</P>
   <PRE>$batch = &lt;&lt;SQLEND;
   SELECT ProductID, UnitPrice, Quantity, Discount
   FROM   [Order Details]
   WHERE  OrderID = \@orderid
SQLEND
%result = $sqlsrv-&gt;sql($batch, {orderid =&gt; [&#39;int&#39;, 11000]},
                       HASH, KEYED, [&#39;ProductID&#39;]);</PRE>
   To get the UnitPrice for product 77 on order 11000, you would say <CODE><SPAN CLASS="nowrap">
   $result{&#39;77&#39;}{UnitPrice}</SPAN></CODE>. As you see in the example, passing <CODE>
   <SPAN CLASS="nowrap">\@keys</SPAN></CODE> as an anonymous array is a normal thing to do.
   <P>
   Here is an example with the <A HREF="#LIST"><SMALL>LIST</SMALL></A> row style and a two-column key:</P>
<PRE>$batch = &lt;&lt;SQLEND;
   SELECT O.CustomerID, OD.ProductID, OD.UnitPrice, OD.Quantity,
          OD.Discount
   FROM   Orders O
   JOIN   [Order Details] OD ON O.OrderID = OD.OrderID
   WHERE  O.OrderID = \@orderid
SQLEND
$result = $sqlsrv-&gt;sql($batch, {orderid =&gt; [&#39;int&#39;, 11000]},
                       LIST, KEYED, [1, 2]);</PRE>Now the unit price for product 77 is at
<CODE><SPAN CLASS="nowrap">$$result{RATTC}{&#39;77&#39;}[0]</SPAN></CODE>. (<SMALL>RATTC</SMALL> is the customer on
   order 11000). The customer ID is the first since we in <CODE><SPAN CLASS="nowrap">\@keys</SPAN></CODE>
   said 1 before 2. The index for UnitPrice is 0, because UnitPrice is the first
   non-key column.
   <P>The keys you provide in <CODE><SPAN CLASS="nowrap">\@keys</SPAN></CODE> are supposed to be the unique
      keys of your result set, and appear in all rows of the result set(s). If a
      key listed in <CODE><SPAN CLASS="nowrap">\@keys</SPAN></CODE> does not appear in one of the rows, this
      is an error, and Win32::SqlServer will <CODE>croak</CODE>.
      If a key value appears more than once in the result, Win32::SqlServer emits a
      warning if Perl warnings are activated. It is undefined which of the 
   duplicate rows that
      end up in the result set. Finally, if there are <SMALL>NULL</SMALL> values in your key
      columns, they wind up as <CODE>undef</CODE> on the Perl side, and Perl
      will give you warnings about this. You may prefer to use
      <SMALL><SPAN CLASS="nowrap">COALESCE()</SPAN></SMALL> or <SMALL><SPAN CLASS="nowrap">ISNULL()</SPAN></SMALL> in your query to avoid this.</P></DD>

   <DT><B><A NAME="NORESULT">NORESULT</A></B></DT>
   <DD>This means that whatever result set there may be, throw it away. The
   return value is <CODE>undef</CODE> or an empty array. The gains with <A HREF="#NORESULT"><SMALL>NORESULT</SMALL></A>
   are limited. Win32::SqlServer performs a <A HREF="#cancelresultset"><SPAN CLASS="nowrap">cancelresultset()</SPAN></A>
   on each result set, but most data probably crosses the wire anyway. But may you save
   some client-side cycles on not building arrays of hashes and that. </DD>
   <DT>&nbsp;</DT>
   <DT><B><A NAME="Callbacks">Callbacks</A></B></DT>
   <DD>Rather getting all data back at once, you can receive them one at a time
   by passing a reference to a Perl
     <CODE>sub </CODE>for <CODE><SPAN CLASS="nowrap">$resultstyle</SPAN></CODE>. Win32::SqlServer calls this <CODE>sub</CODE> once for each row
   that is returned from the query. <CODE>$rowstyle</CODE> then controls how
   the row is passed:
   <PRE>$retstat = &amp;$callback(\%row, $resultset_no); # HASH
$retstat = &amp;$callback(\@row, $resultset_no); # LIST
$retstat = &amp;$callback($row,  $resultset_no); # SCALAR</PRE><CODE>$resultset_no</CODE> tells you which result set the row comes from. The
   result sets are numbered from 1 and up.
   <P>The callback should return any of the integer numbers as detailed below. The
   return value from the last call to the callback is the return value from
      <A HREF="#sql"><SPAN CLASS="nowrap">sql()</SPAN></A>.</P>
   <DL>
      <DT><B><A NAME="RETURN_NEXTROW">RETURN_NEXTROW</A></B></DT>
      <DD>Tells Win32::SqlServer to give you the next row (if there is one, that is). This is
   the &quot;normal&quot; return value. I usually don&#39;t leak constant values, but if you
   think <A HREF="#RETURN_NEXTROW"><SMALL>RETURN_NEXTROW</SMALL></A> is too noisy, I can reveal that 1 will do the same task.</DD>
      <DT>&nbsp;</DT>
      <DT><B><A NAME="RETURN_NEXTQUERY">RETURN_NEXTQUERY</A></B></DT>
      <DD>Quit returning rows from the current result set, and move to the next
   result set.</DD>
      <DT>&nbsp;</DT>
      <DT><B><A NAME="RETURN_CANCEL">RETURN_CANCEL</A></B></DT>
      <DT><B><A NAME="RETURN_ERROR">RETURN_ERROR</A></B></DT>
      <DD>Quit returning rows, and cancel the rest of the query. For
      Win32::SqlServer there
   is not really any difference, but you get a different return value back from
      <A HREF="#sql"><SPAN CLASS="nowrap">sql()</SPAN></A>. Use
      <A HREF="#RETURN_CANCEL"><SMALL>RETURN_CANCEL</SMALL></A>

      when you have found what you were looking for,
      <A HREF="#RETURN_ERROR"><SMALL>RETURN_ERROR</SMALL></A>
   when something went wrong. <A HREF="#RETURN_ERROR"><SMALL>RETURN_ERROR</SMALL></A> has the convenient value of 0.
      <P><B>Important</B>: if you cancel the query with <A HREF="#RETURN_CANCEL"><SMALL>RETURN_CANCEL</SMALL></A> or <A HREF="#RETURN_ERROR"><SMALL>RETURN_ERROR</SMALL></A>, you will not
      receive the value of any output parameters nor the return value from stored procedures.</P>
      </DD>

      <DT><B><A NAME="RETURN_ABORT">RETURN_ABORT</A></B></DT>
      <DD>Something went seriously wrong and you don&#39;t want to live any more.
   Rather than issuing <CODE>die</CODE> yourself, you should use this return
   code. Win32::SqlServer will then free up resources tied to the result set, before it
   aborts execution. This is important in the case you catch the
   condition with <CODE>eval</CODE>, so you don&#39;t have an unprocessed result set
   when you come back from <CODE>eval</CODE></DD>
   </DL>
   <P>A few goods and bads with callbacks:</P>
   <UL>
      <LI><B>Good thing</B>: saves you from dealing with multi-dimensional
      structures, which can be confusing at times. </LI>
      <LI><B>Good thing</B>: if you are retrieving a large result set, you don&#39;t need
   to gather all the data in client before processing them. </LI>
      <LI><B>(Slightly) bad thing</B>: if you want to execute
         <SMALL>SQL</SMALL> statements from your
   callback, you must use another Win32::SqlServer connection for that, as
         Win32::SqlServer does not permit you
   to initiate a new query as long as there are results sets available. <SPAN CLASS="remark">(And, no,
         Win32::SqlServer does not support MARS, Multiple Active
   Result Sets. MARS does not really fit well with the
         Win32::SqlServer
   model.)</SPAN></LI>
      <LI><B>Bad thing</B>: This is the reverse on the second point: if you don&#39;t get
   all data to the client directly, <SMALL>SQL</SMALL> Server needs to hold locks on the data
   for a longer time, which can cause contention problems. From this follows
   that an <SMALL>UPDATE</SMALL> statement from the callback on a second
   connection may cause you to block yourself.</LI>
   </UL>
   <P>All and all, callbacks are not really deprecated, but they do smell a 
   little funny. </P>
   </DD>
</DL>
If you want more examples on row styles and result styles, please refer to the

<A HREF="#quickexamples">Quick Examples</A> above. There is also an
<A HREF="#sqlsp_examples">example of using a callback</A> in the topic of
<A HREF="#sql_sp"><SPAN CLASS="nowrap">sql_sp()</SPAN></A>.
<P>This table summarises how
   you could refer the column <I>col</I> in the first row in the first result
   set, given a row style, result style and the type of return value. The
colinfo style is assumed to be <A HREF="#COLINFO_NONE"><SMALL>COLINFO_NONE</SMALL></A>. For
   <A HREF="#SCALAR"><SMALL>SCALAR</SMALL></A>, the assumption is that there is only one column to retrieve. If a
   cell is greyed, that combination is not useful or not applicable.</P>
<P>
<TABLE BORDER=1 CELLSPACING=0 CELLPADDING=2>
<THEAD><TR><TD>&nbsp;</TD><TD>&nbsp;</TD><TH><A HREF="#HASH"><SMALL>HASH</SMALL></A></TH><TH><A HREF="#LIST"><SMALL>LIST</SMALL></A></TH><TH><A HREF="#SCALAR"><SMALL>SCALAR</SMALL></A></TH></TR>
</THEAD>
<TR><TH ROWSPAN="3"><SMALL><A HREF="#MULTISET">MULTISET</A></SMALL><BR />
   <A HREF="#MULTISET_RC"><SMALL>MULTISET_RC</SMALL></A></TH>
    <TH><CODE><SPAN CLASS="nowrap">%res</SPAN></CODE></TH>
       <TD BGCOLOR="#999999"><CODE>&nbsp;</CODE></TD>
       <TD BGCOLOR="#999999"><CODE>&nbsp;</CODE></TD>
       <TD BGCOLOR="#999999"><CODE>&nbsp;</CODE></TD></TR>
<TR><TH><CODE><SPAN CLASS="nowrap">@res</SPAN></CODE></TH>
     <TD><CODE>$res[0][0]{&#39;col&#39;}</CODE></TD>
    <TD><CODE>$res[0][0][$colno]</CODE></TD>
    <TD><CODE>$res[0][0]</CODE></TD></TR>
<TR><TH><CODE>$res</CODE></TH>
    <TD><CODE>$$res[0][0]{&#39;col&#39;}</CODE></TD>
    <TD><CODE>$$res[0][0][$colno]</CODE></TD>
    <TD><CODE>$$res[0][0]</CODE></TD></TR>
<TR><TH ROWSPAN="3"><A HREF="#SINGLESET"><SMALL>SINGLESET</SMALL></A></TH>
    <TH><CODE><SPAN CLASS="nowrap">%res</SPAN></CODE></TH>
        <TD BGCOLOR="#999999"><CODE>&nbsp;</CODE></TD>
        <TD BGCOLOR="#999999"><CODE>&nbsp;</CODE></TD>
        <TD BGCOLOR="#999999"><CODE>&nbsp;</CODE></TD></TR>
<TR><TH><CODE><SPAN CLASS="nowrap">@res</SPAN></CODE></TH>
    <TD><CODE>$res[0]{&#39;col&#39;}</CODE></TD>
    <TD><CODE>$res[0][$colno]</CODE></TD>
    <TD><CODE>$res[0]</CODE></TD></TR>
<TR><TH><CODE>$res</CODE></TH>
    <TD><CODE>$$res[0]{&#39;col&#39;}</CODE></TD>
    <TD><CODE>$$res[0][$colno]</CODE></TD>
    <TD><CODE>$$res[0]</CODE></TD></TR>
<TR><TH ROWSPAN="3"><A HREF="#SINGLEROW"><SMALL>SINGLEROW</SMALL></A></TH>
    <TH><CODE><SPAN CLASS="nowrap">%res</SPAN></CODE></TH>
       <TD><CODE>$res{&#39;col&#39;}</CODE></TD>
       <TD BGCOLOR="#999999"><CODE>&nbsp;</CODE></TD>
       <TD BGCOLOR="#999999"><CODE>&nbsp;</CODE></TD></TR>
<TR><TH><CODE><SPAN CLASS="nowrap">@res</SPAN></CODE></TH>
    <TD BGCOLOR="#999999"><CODE>&nbsp;</CODE></TD>
    <TD><CODE>$res[$colno]</CODE></TD>
    <TD><CODE>$res[0]</CODE></TD></TR>
<TR><TH><CODE>$res</CODE></TH>
    <TD><CODE>$$res{&#39;col&#39;}</CODE></TD>
    <TD><CODE>$$res[$colno]</CODE></TD>
    <TD><CODE>$res</CODE></TD></TR>
<TR><TH ROWSPAN="3"><A HREF="#KEYED"><SMALL>KEYED</SMALL></A></TH>
    <TH><CODE><SPAN CLASS="nowrap">%res</SPAN></CODE></TH>
        <TD><CODE>$res{&#39;key&#39;}{&#39;col&#39;}</CODE></TD>
        <TD><CODE>$res{&#39;key&#39;}[$colno]</CODE></TD>
        <TD><CODE>$res{&#39;key&#39;}</CODE></TD></TR>
<TR><TH><CODE><SPAN CLASS="nowrap">@res</SPAN></CODE></TH>
    <TD BGCOLOR="#999999"><CODE>&nbsp;</CODE></TD>
    <TD BGCOLOR="#999999"><CODE>&nbsp;</CODE></TD>
    <TD BGCOLOR="#999999"><CODE>&nbsp;</CODE></TD></TR>
<TR><TH><CODE>$res</CODE></TH>
    <TD><CODE>$$res{&#39;key&#39;}{&#39;col&#39;}</CODE></TD>
    <TD><CODE>$$res{&#39;key&#39;}[$colno]</CODE></TD>
    <TD><CODE>$$res{&#39;key&#39;}</CODE></TD></TR>
</TABLE>
<BR/>
</P>
<H3><A NAME="colinfostyles">Getting Column Information</A></H3>
<BR />
<P>Sometimes you want to get information about the columns in the result set(s)
you are receiving. For instance, you want to write a generic export utility that
performs <CODE><SPAN CLASS="nowrap">SELECT *</SPAN></CODE> on some table or views or runs
a set of stored procedures, and you don&#39;t want the utility to have knowledge of what
columns they produce. You just want to write them to a file, with the column
names on the first line, and maybe you also want to put character columns in
quotes. To this end, you can use the fourth parameter of <A HREF="#sql"><SPAN CLASS="nowrap">sql()</SPAN></A>, <CODE>$colinfostyle</CODE>.
There are four possible values for this parameter:</P>
<DL>
   <DT><A NAME="COLINFO_NONE"><B>COLINFO_NONE</B></A> (Default)</DT>
   <DD>Do not return any column information. This is
   the only permitted colinfo style, if the result style is any of <SMALL>
   <A HREF="#SINGLEROW">SINGLEROW</A>,
   <A HREF="#NORESULT">NORESULT</A></SMALL> or <A HREF="#KEYED"><SMALL>KEYED</SMALL></A>.</DD>
   <DT>&nbsp;</DT>
   <DT><A NAME="COLINFO_NAMES"><B>COLINFO_NAMES</B></A></DT>
   <DD>Prepend an extra row to the result set(s) with the column names. Note
   that in difference to the hash keys with row style <A HREF="#HASH"><SMALL>HASH</SMALL></A>, the names are
   exactly those as returned by <SMALL>SQL</SMALL> Server. Nameless columns will appear as
   the empty string, and if there are duplicate names, they are retained. This
   colinfo style is mainly useful with the <A HREF="#LIST"><SMALL>LIST</SMALL></A> and <A HREF="#SCALAR"><SMALL>SCALAR</SMALL></A> row styles. It is
   still permitted with <A HREF="#HASH"><SMALL>HASH</SMALL></A>.</DD>
   <DT>&nbsp;</DT>
   <DT><A NAME="COLINFO_POS"><B>COLINFO_POS</B></A></DT>
   <DD>Prepend an extra row to the result set(s) with the column positions. The
   positions are numbered from 1 and up. This colinfo style is mainly useful
   with the <A HREF="#HASH"><SMALL>HASH</SMALL></A> row style, but it is still permitted with <A HREF="#LIST"><SMALL>LIST</SMALL></A> and <A HREF="#SCALAR"><SMALL>SCALAR</SMALL></A>.</DD>
   <DT>&nbsp;</DT>
   <DT><A NAME="COLINFO_FULL"><B>COLINFO_FULL</B></A></DT>
   <DD>Prepend a extra row to the result set(s) where each entry is a reference
   to a hash with the following keys:
   <B>Colno</B>, <B>Name</B>, <B>Type</B>, <B>Maxlength</B>, <B>Precision</B>,
   <B>Scale</B>, <B>Maybenull</B> and <B>Readonly</B>. For further details of
   these values, see the description of <A HREF="#getcolumninfo"><SPAN CLASS="nowrap">getcolumninfo()</SPAN></A>. <A HREF="#COLINFO_FULL"><SMALL>COLINFO_FULL</SMALL></A> is only
   permitted with the row styles <A HREF="#HASH"><SMALL>HASH</SMALL></A> and <A HREF="#LIST"><SMALL>LIST</SMALL></A>; it is not permitted with
   <A HREF="#SCALAR"><SMALL>SCALAR</SMALL></A>. </DD>
</DL>
<P>To understand this a little better, let&#39;s look at this example:</P>
<PRE>$orderid = 11000;
$sqlstring = &lt;&lt;SQLEND;
   SELECT OrderDate, CustomerID, EmployeeID, ShippedDate
   FROM   Orders
   WHERE  OrderID = \@orderid
   SELECT ProductID, UnitPrice, Quantity, Discount
   FROM   [Order Details]
   WHERE  OrderID = \@orderid
   ORDER  BY ProductID
SQLEND
@result = $sqlsrv-&gt;sql($sqlstring, {orderid =&gt; [&#39;int&#39;, $orderid]},
                       MULTISET, LIST, COLINFO_NAMES);</PRE>
<P>In <CODE>$result[0][0][0]</CODE> you will find <I>OrderDate</I>, the name of
the first column in the first result set. Similarly, <CODE><SPAN CLASS="nowrap">
$result[0][0][2]</SPAN></CODE> is <I>EmployeeID</I>, and <CODE><SPAN CLASS="nowrap">
$result[0][1][1]</SPAN></CODE> is <SMALL>RATTC</SMALL>, the customer for order 11000 in the
Northwind database. <CODE><SPAN CLASS="nowrap">$result[1][0][1]</SPAN></CODE> has the value <I>
UnitPrice</I>, the name of the second column in the second result set. And <CODE>
<SPAN CLASS="nowrap">$result[1][2][2]</SPAN></CODE> is 30, the quantity for the second product
on order 11000.</P>
<P>If we change the colinfo style to <A HREF="#COLINFO_FULL"><SMALL>COLINFO_FULL</SMALL></A>, to find the string <I>
OrderDate</I>, you would now have to say <CODE><SPAN CLASS="nowrap">$result[0][0][0]{Name}</SPAN></CODE>,
and if you look in <CODE><SPAN CLASS="nowrap">$result[1][0][1]{Type}</SPAN></CODE> you would
find that the data type for UnitPrice is <I>money</I>.</P>
<P>Let&#39;s now move back to <A HREF="#COLINFO_NAMES"><SMALL>COLINFO_NAMES</SMALL></A>, and change <A HREF="#MULTISET"><SMALL>MULTISET</SMALL></A> to <A HREF="#SINGLESET"><SMALL>SINGLESET</SMALL></A>. Not
surprisingly, the string <I>OrderDate </I>is now at <CODE><SPAN CLASS="nowrap">$result[0][0]</SPAN></CODE>,
and at <CODE><SPAN CLASS="nowrap">$result[1][1]</SPAN></CODE> is the customer <SMALL>ID, RATTC</SMALL>. But
what is at <CODE><SPAN CLASS="nowrap">$result[2][0]</SPAN></CODE>? No, it is not the string <I>
ProductID</I>, but instead the value 4, the ID for the first product of order
11000. This is because with <A HREF="#SINGLESET"><SMALL>SINGLESET</SMALL></A> you only get column information
for the
first result set, even if there happens to be multiple result sets. After all,
<A HREF="#SINGLESET"><SMALL>SINGLESET</SMALL></A> is mainly intended for batches that return a single result set, and
the prime use for multiple results with <A HREF="#SINGLESET"><SMALL>SINGLESET</SMALL></A> is maybe when all sets have the same columns.</P>
<P>Thus, the only result styles for which you can get full column information is
<SMALL><A HREF="#MULTISET">MULTISET</A>, <A HREF="#MULTISET_RC">MULTISET_RC</A></SMALL> and callbacks. For <A HREF="#SINGLESET"><SMALL>SINGLESET</SMALL></A> you can only get it for first
result set. And for <SMALL><A HREF="#SINGLEROW">SINGLEROW</A>,
<A HREF="#NORESULT">NORESULT</A></SMALL> and <SMALL>
<A HREF="#KEYED">KEYED</A>, <A HREF="#COLINFO_NONE">COLINFO_NONE</A></SMALL> is the only
permitted value. </P>
<P>See also Example 3 in the <A HREF="#quickexamples">Quick Examples</A> section
for an example using <A HREF="#COLINFO_NAMES"><SMALL>COLINFO_NAMES</SMALL></A>.</P>
<H2><A NAME="sql_one"><SPAN CLASS="nowrap">sql_one()</SPAN></A></H2>
<P>Executes a command batch that should return exactly one row and <CODE>croaks</CODE> if it
   does not.</P>
<PRE>(%|@|$)result = $sqlsrv-&gt;sql_one($batch [, \@unnamed_parameters]
                                        [, \%named_paraeters] [, $rowstyle]);</PRE>
<DL>
   <DT><CODE>(%|@|$)result</CODE></DT>
   <DD>The result set from the command batch. If <CODE>$rowstyle</CODE> is
   <A HREF="#HASH"><SMALL>HASH</SMALL></A> (the default), the result is a hash or a reference to a hash. It <CODE>
   $rowstyle</CODE> is <A HREF="#LIST"><SMALL>LIST</SMALL></A>, the result is an array or a reference to an array.
   If <CODE>$rowstyle</CODE> is <A HREF="#SCALAR"><SMALL>SCALAR</SMALL></A>, the result is a scalar value. </DD>
   <DT>&nbsp;</DT>
   <DT><CODE>$batch</CODE></DT>
   <DD>A batch of one or more <SMALL>SQL</SMALL> statements that is expected to return exactly
   one row.</DD>
   <DT>&nbsp;</DT>
   <DT><CODE>\@unnamed_parameters</CODE></DT>
   <DD>A reference to an array with input for unnamed parameters. This parameter
   works exactly as the namesake parameter for <A HREF="#sql"><SPAN CLASS="nowrap">sql()</SPAN></A>, see
   further this function and particularly the section
   <A HREF="#parameterspecdetails">Details on the Parameter Specification</A>. </DD>
   <DT>&nbsp;</DT>
   <DT><CODE>\%named_parameters</CODE></DT>
   <DD>A reference to a hash with input for named parameters. This parameter
   works exactly as the namesake parameter for <A HREF="#sql"><SPAN CLASS="nowrap">sql()</SPAN></A>, see
   further this function and particularly the section
   <A HREF="#parameterspecdetails">Details on the Parameter Specification</A>.</DD>
   <DT>&nbsp;</DT>
   <DT><CODE>$rowstyle</CODE></DT>
   <DD>Specifies how each row in the result is to be represented. Possible
   values are <A HREF="#HASH"><SMALL>HASH</SMALL></A> (each row is a hash keyed by column name), <A HREF="#LIST"><SMALL>LIST</SMALL></A> (each
   row is an array) and <A HREF="#SCALAR"><SMALL>SCALAR</SMALL></A> (each row is a scalar value). See the section
   <A HREF="#RowResultStyles">Row Styles and Result Styles</A> under
   <A HREF="#sql"><SPAN CLASS="nowrap">sql()</SPAN></A> for details. Default is <A HREF="#HASH"><SMALL>HASH</SMALL></A>.</DD>
</DL>
<P><A HREF="#sql_one"><SPAN CLASS="nowrap">sql_one()</SPAN></A> is similar to <A HREF="#sql"><SPAN CLASS="nowrap">sql()</SPAN></A> with <CODE>$resultstyle</CODE>
   set to <A HREF="#SINGLEROW"><SMALL>SINGLEROW</SMALL></A>, but there is one important
   difference: <A HREF="#sql_one"><SPAN CLASS="nowrap">sql_one()</SPAN></A> will <CODE>croak</CODE> if the command batch returns
   more than one row or no row at all.</P>
<H2><A NAME="sql_sp"><SPAN CLASS="nowrap">sql_sp()</SPAN></A></H2>
<P>Executes a stored procedure or a scalar user-defined function. </P>
<PRE>($|@|%)result = $sqlsrv-&gt;sql_sp($SP_name
                                [, \$retvalue]
                                [, \@positional_parameters]
                                [, \%named_parameters]
                                [, $colinfostyle] [, $rowstyle]
                                [, $resultstyle [, \@keys]]);</PRE>
<H3>Parameters</H3>
<DL>
   <DT><CODE>($|@|%)result</CODE></DT>
   <DD>The result set(s) from the stored procedure. The result set is returned
   in exactly the same fashion as for <A HREF="#sql"><SPAN CLASS="nowrap">sql()</SPAN></A>, please refer to
   that function and the section <A HREF="#RowResultStyles">Row Styles and
   Result Styles</A>.</DD>
   <DT>&nbsp;</DT>
   <DT><CODE>$SP_name</CODE></DT>
   <DD>The name of a stored procedure or a scalar user-defined function. This
   can be a one-, two- or three-part name. That is, you can supply database
   and/or schema. Four-part names including a server-component are
   not permitted. If any component of the name includes special characters
   such as space or period, quote that component with brackets or double quotes as
   you would in <SMALL>T-SQL</SMALL>, for instance:
   <PRE>$sqlsrv-&gt;sql_sp(&#39;[My.Database].thisschema.&quot;that sp&quot;&#39;);</PRE>
   </DD>
   <DT><CODE>\$retvalue</CODE></DT>
   <DD>A reference to a scalar that will receive the return value of the stored
   procedure or the user-defined function. See further the section
   <A HREF="#Return_values">Return Values</A> below.</DD>
   <DT>&nbsp;</DT>
   <DT><CODE>\@positional_parameters</CODE></DT>
   <DD>A reference to an array that holds unnamed parameters. The parameters
   must appear in the order they appear in the declaration of the stored
   procedure or <SMALL>UDF</SMALL>. The entries in the array are
   scalar values, or reference to scalars. See further the section <A HREF="#SP_parameters">Passing Parameters to Stored
   Procedures</A> below. Note that parameters to stored procedures works differently from
   parameters to command batches with <A HREF="#sql"><SPAN CLASS="nowrap">sql()</SPAN></A>.</DD>
   <DT>&nbsp;</DT>
   <DT><CODE>\%named_parameters</CODE></DT>

   <DD>A reference to a hash for named parameters. The keys in the hash are the
   parameter names, with or without the leading <CODE>@</CODE>. (If you specify
   both, Win32::SqlServer discards one of them and issues a warning.) The hash entries are scalar values, or reference to scalars. If you have specified
   the same parameter in <CODE><SPAN CLASS="nowrap">\@positional_parameters</SPAN></CODE> and
   <CODE><SPAN CLASS="nowrap">\%named_parameters</SPAN></CODE>, the entry in <CODE><SPAN CLASS="nowrap">\@positional_parameters</SPAN></CODE>
   takes precedence and the other value is discarded, yielding a warning through
   the <A HREF="#MsgHandler">current message handler</A>, if Perl warnings are
   enabled. For further details, see the section <A HREF="#SP_parameters">Passing Parameters to Stored Procedures</A>
   below. Note that
   parameters to stored procedures works differently from parameters to command
   batches with <A HREF="#sql"><SPAN CLASS="nowrap">sql()</SPAN></A>.</DD>
   <DT>&nbsp;</DT>
   <DT><CODE>$colinfostyle</CODE></DT>
   <DD>Specifies if and how you want information about the columns in the
   result set(s). Possible values are <A HREF="#COLINFO_NONE"><SMALL>COLINFO_NONE</SMALL></A> (no information),
   <A HREF="#COLINFO_NAMES"><SMALL>COLINFO_NAMES</SMALL></A> (names only), <A HREF="#COLINFO_POS"><SMALL>COLINFO_POS</SMALL></A> (column numbers only) and
   <A HREF="#COLINFO_FULL"><SMALL>COLINFO_FULL</SMALL></A> (a hash with detailed information about the columns). This
   parameter works exactly as for <A HREF="#sql"><SPAN CLASS="nowrap">sql()</SPAN></A>. See the section
   <A HREF="#colinfostyles">Getting Column Information</A> under that function
   for details. The default is <A HREF="#COLINFO_NONE"><SMALL>COLINFO_NONE</SMALL></A>.</DD>
   <DT>&nbsp;</DT>
   <DT><CODE>$rowstyle</CODE></DT>

   <DD>Specifies how each row in the result is to be represented. Possible
   values are <A HREF="#HASH"><SMALL>HASH</SMALL></A> (each row is a hash keyed by column
   name),
   <A HREF="#LIST"><SMALL>LIST</SMALL></A> (each row is an array) and <A HREF="#SCALAR"><SMALL>SCALAR</SMALL></A>
   (each row is a scalar value). This parameter works exactly as for
   <A HREF="#sql"><SPAN CLASS="nowrap">sql()</SPAN></A>. See the section <A HREF="#RowResultStyles">Row Styles and Result Styles</A>
   under that function. Default is <A HREF="#HASH"><SMALL>HASH</SMALL></A>.</DD>
   <DT>&nbsp;</DT>
   <DT><CODE>$resultstyle</CODE></DT>
   <DD>Specifies how the result sets are structured. Possible values are
   <A HREF="#MULTISET"><SMALL>MULTISET</SMALL></A> (an array of result sets),
   <A HREF="#MULTISET_RC"><SMALL>MULTISET_RC</SMALL></A> (an array of result sets and row counts for action statements),
   <A HREF="#SINGLESET"><SMALL>SINGLESET</SMALL></A> (an array of rows),
   <A HREF="#SINGLEROW"><SMALL>SINGLEROW</SMALL></A>
   (a single row according to <CODE>$rowstyle</CODE>), <A HREF="#KEYED"><SMALL>KEYED</SMALL></A>
   (a hash, keyed by the data in the result set), <A HREF="#NORESULT"><SMALL>NORESULT</SMALL></A>
   (no result set returned) or a reference to a
   <A HREF="#Callbacks">callback</A> routine called for each row. This
   parameter works exactly as for <A HREF="#sql"><SPAN CLASS="nowrap">sql()</SPAN></A>. See the section
   <A HREF="#RowResultStyles">Row Styles and Result Styles</A> under that
   function. Default is
   <A HREF="#SINGLESET"><SMALL>SINGLESET</SMALL></A>.</DD>
   <DT>&nbsp;</DT>
   <DT><CODE>\@keys</CODE></DT>
   <DD>This parameter is only applicable when <CODE>$resultstyle</CODE> is
   <A HREF="#KEYED"><SMALL>KEYED</SMALL></A>, in which case it&#39;s mandatory. It specifies which
   column(s) in the result that is/are the keys. See further the section
   <A HREF="#RowResultStyles">Row Styles and Result Styles</A> under the topic
   of <A HREF="#sql"><SPAN CLASS="nowrap">sql()</SPAN></A>. </DD>
</DL>
<H3>General</H3>
<P><A HREF="#sql_sp"><SPAN CLASS="nowrap">sql_sp()</SPAN></A> uses the <SMALL>RPC</SMALL> mechanism to call the stored procedure or <SMALL>UDF</SMALL>, and does
   thus not issue any <SMALL>EXEC</SMALL> statement. The <SMALL>RPC</SMALL> mechanism is a
   faster way to call a stored procedure.</P>
<P>Note that there is one case you will not get the return value or the value
   of the output parameters: this is when you use a <A HREF="#Callbacks">callback</A> routine as the result
   style, and you return <A HREF="#RETURN_CANCEL"><SMALL>RETURN_CANCEL</SMALL></A> or <A HREF="#RETURN_ERROR"><SMALL>RETURN_ERROR</SMALL></A> from the callback. In
   this case, the query is cancelled, whereupon output parameters and return
   value are lost.</P>
<H3><A NAME="Return_values">Return Values</A></H3>
<P>If a stored procedure returns another value than zero, the default behaviour
   of <A HREF="#sql_sp"><SPAN CLASS="nowrap">sql_sp()</SPAN></A> is to <CODE>croak</CODE>. The assumption is that a stored procedure
   returns 0 on successful execution, and any non-zero value indicates failure.
   There is no requirement in <SMALL><SPAN CLASS="nowrap">T-SQL</SPAN></SMALL> that you must use return values this way,
   but it&#39;s definitely best practice to do so. To return actual data values from stored
   procedures, use output parameters instead.</P>
<P>You can override this behaviour with the <B><A HREF="#CheckRetStat">CheckRetStat</A></B> and <B><A HREF="#RetStatOK">RetStatOK</A></B> elements
   of the <B><A HREF="#ErrInfo">ErrInfo</A></B> property.</P>
<P>This does not apply when you call scalar user-defined functions. In this case
   <A HREF="#sql_sp"><SPAN CLASS="nowrap">sql_sp()</SPAN></A> never aborts execution because of the return value. </P>
<H3><A NAME="SP_parameters">Parameters to Stored Procedures</A></H3>
<P>(For brevity, I&#39;m saying &quot;stored procedures&quot; in this section, but everything
   which is said here applies to scalar user-defined functions as well. Except,
   then, that they don&#39;t have output parameters.)</P>
<H4>Win32::SqlServer Retrieves and Caches Parameter Profiles</H4>
<P>When you call a stored procedure with <A HREF="#sql_sp"><SPAN CLASS="nowrap">sql_sp()</SPAN></A>, you don&#39;t have to bother
   about the data types of the parameters, because the first time you call the
   procedure Win32::SqlServer queries <SMALL>SQL</SMALL>
   Server to get the parameter profile of the stored procedure. On subsequent
   calls, Win32::SqlServer retrieves the parameter profile from its cache in
   the Win32::SqlServer property <B><A HREF="#procs">procs</A></B>. This property is a
   hash keyed by the procedure name, exactly as you specified it, so <B>my_sp</B> and
   <B>dbo.my_sp</B> result in two entries in <B><A HREF="#procs">procs</A></B>. 
Win32::SqlServer never clears the cache. This means that if you first connect to 
one database and call <B>my_sp</B> in that database and then use the same 
Win32::SqlServer object to connect to another database and call a <B>my_sp</B> 
in that database, Win32::SqlServer will use the cached parameter profile. If the 
two databases are instances of the same database schema, this makes sense. If not, either 
prepend the database name to the procedure name in the call to <A HREF="#sql_sp"><SPAN CLASS="nowrap">sql_sp()</SPAN></A>, or 
delete the old procedure entry from <B><A HREF="#procs">procs</A></B>. Or simply 
access the two databases from different Win32::SqlServer objects. The same 
applies if your script would recreate a procedure with a different parameter profile. (As for the contents of the entry in <B>
<A HREF="#procs">procs</A></B>, that is off-limits. Any meddling is entirely
   unsupported.)</P>
<P>A consequence of this is that there are some special system stored procedures
   that you cannot call with <A HREF="#sql_sp"><SPAN CLASS="nowrap">sql_sp()</SPAN></A> because they have dynamic parameter lists.
   One such example is <B>sp_executesql</B>. For such procedures, call them
   through <A HREF="#sql"><SPAN CLASS="nowrap">sql()</SPAN></A> using <SMALL>EXEC</SMALL> instead, or use the
   <A HREF="#Mid-level">mid-level query routines</A>.</P>
<H4>Passing Values In and Out</H4>
<P>Each entry in <CODE><SPAN CLASS="nowrap">\@positional_parameters</SPAN></CODE> and <CODE>
   <SPAN CLASS="nowrap">\%named_parameters</SPAN></CODE> is a parameter value, or a reference
   to a parameter value. The latter is necessary for output parameters when you
   use an anonymous array or hash to pass the parameters. </P>
<P>Say that you have this stored procedure:</P>
<PRE>CREATE PROCEDURE some_sp @in int,
                         @out int OUTPUT AS</PRE>
The proper way to call this procedure is:
<PRE>my ($out);
$sqlsrv-&gt;sql_sp(&#39;some_sp&#39;, [1, \$out]);</PRE>
<P>That is, in the array you must pass a <I>reference</I> to the variable that
   is to receive the value in the output parameter. If you just passed <CODE>$out</CODE>,
   then Win32::SqlServer would modify the entry in the anonymous array, but <CODE>$out</CODE>
   would be unchanged. For this reason, <A HREF="#sql_sp"><SPAN CLASS="nowrap">sql_sp()</SPAN></A> issues a warning, if an array/hash
   entry for an output parameter is not a reference to a scalar. The warning is
   only issued if Perl warnings are enabled.</P>
<P>(Yes, if you use a real array and not an anonymous one, like this:</P>
<PRE>my @params = (1, undef);
$sqlsrv-&gt;sql_sp(&#39;some_sp&#39;, \@params);</PRE>
<P>
<CODE>$params[1]</CODE> is set to the value of <CODE><SPAN CLASS="nowrap">@out</SPAN></CODE>, despite not being a
reference. Thus, in this case the warning is incorrect. But there is no way for
<A HREF="#sql_sp"><SPAN CLASS="nowrap">sql_sp()</SPAN></A> to tell whether you passed an anonymous or a real array, and I expect anonymous arrays to be used more
often than real.)</P>
<P>As for how to specify the actual values for different data types, see the
   section <A HREF="#datatypes">Data-type Representation</A>. For table-valued
parameters, see just below.</P>
<H3>&nbsp;<A NAME="sqlsp_examples">Examples</A></H3>
<P><B>sp_helpdb</B> returns two result sets. Here is an example using a
   <A HREF="#Callbacks">callback</A>
   that prints out the result sets in a fairly simple manner:</P>
<PRE>sub print_hash {
   my($hash, $ressetno) = @_;
   my ($col);
   print &quot;$ressetno: &quot;;
   foreach $col (%$hash) {
      print &quot;$col: $$hash{$col} &quot;;
   }
   print &quot;\n&quot;;
   RETURN_NEXTROW;
}
$sqlsrv-&gt;sql_sp(&quot;sp_helpdb&quot;, [&#39;tempdb&#39;], HASH, \&amp;print_hash);</PRE>
<P>Here is an example with a procedure that takes two dates as parameters to
   count the number of records in that interval. Passing <SMALL>NULL</SMALL> means no limit in
   that direction. The SP permits you to restrict the count to records of a
   certain flavour. The count is returned in an output parameter. There are no
   result sets.</P>

<PRE>CREATE PROCEDURE putte_sp @startdate datetime = NULL,
                          @enddate   datetime = NULL,
                          @flavour   smallint = NULL,
                          @no_of_rec int      OUTPUT AS</PRE>

<P>Say we want to know how many records there are from 1997 and on, of all
   flavours, and we also want the return value. In <SMALL><SPAN CLASS="nowrap">T-SQL</SPAN></SMALL> the call would be:</P>
<PRE>EXEC @ret = putte_sp &#39;19970101&#39;, @no_of_rec = @no_of_rec OUTPUT</PRE>
<P>In Win32::SqlServer this translates to:</P>
<PRE>$sqlsrv-&gt;sql_sp(&#39;putte_sp&#39;, \$ret, [&#39;19970101&#39;], {&#39;no_of_rec&#39; =&gt; \$no_of_rec});</PRE>
<P>Notice how we pass a reference to <CODE>$no_of_rec</CODE>, rather than the
   variable itself, so we can retrieve the output value later on. We also left
   out the <CODE>@</CODE> from the hash key, knowing that Win32::SqlServer sorts
it out anyway. </P>
<H2><A NAME="sql_insert"><SPAN CLASS="nowrap">sql_insert()</SPAN></A></H2>
<P>
Inserts a row in to table from a hash, using the keys in the hash as column
names. </P>
<PRE>$sqlsrv-&gt;sql_insert($table, \%values);</PRE>
<DL>
   <DT><CODE>$table</CODE></DT>
   <DD>The name of a table or a view to insert into. The name can be a one-, two-
   or three-part name. That is, you can specify database, schema and table. You
   cannot use a four-part name to specify a remote table. If any component
   includes special characters, you must put that component in brackets or
   double quotes as in this example:</DD>
   <PRE>$sqlsrv-&gt;sql_insert(&#39;&quot;My.Database&quot;..[Order Details]&#39;, \%order_details);</PRE>
   <DT><CODE>\%values</CODE></DT>
   <DD>
   A reference to a hash which holds the values to insert. The keys of the hash
   should agree with the column names of the table.</DD>
</DL>
<P>On the first invocation for a certain table, <A HREF="#sql_insert"><SPAN CLASS="nowrap">sql_insert()</SPAN></A> inquires the system tables in <SMALL>SQL</SMALL> Server to find out the data
   types of all columns. This information is saved in the Win32::SqlServer property <B>
   <A HREF="#tables">tables</A></B>, and <A HREF="#sql_insert"><SPAN CLASS="nowrap">sql_insert()</SPAN></A> uses the cached
   information on subsequent calls. <B><A HREF="#tables">tables</A></B> is a
   hash. You can force a refresh by deleting the hash key
  for a table. The key is exactly as you entered it, thus &quot;Orders&quot;
  and &quot;orders&quot; are different tables in this context, even if you have a
  case-insensitive database.</P>
<P>As for specifying the data in the columns, please see the section
   <A HREF="#datatypes">Data-type Representation</A>.</P>
<P><A HREF="#sql_insert"><SPAN CLASS="nowrap">sql_insert()</SPAN></A> results in a parameterised call to <A HREF="#sql"><SPAN CLASS="nowrap">sql()</SPAN></A>, and eventually
   <B>sp_executesql</B>. Thus, there will be a cached query plan, which is good
for performance. Nevertheless, if you have a lot of data to insert, there are several alternatives that are better: table-valued parameter (<SMALL>SQL</SMALL> 2008 or later), <SMALL>XML</SMALL> or <SMALL>BCP</SMALL>.</P>
<H2><A NAME="TVP">Working with Table Parameters</A></H2>
<P>Table-valued parameters were added in <SMALL>SQL</SMALL> Server 2008. To use
table-valued parameters, you need to use the <SMALL>SQLNCLI10</SMALL> provider or later. Table-valued parameters are read-only. This section
covers how you work with table parameters with the high-level routines <A HREF="#sql"><SPAN CLASS="nowrap">sql()</SPAN></A>,
<A HREF="#sql_one"><SPAN CLASS="nowrap">sql_one()</SPAN></A> and
<A HREF="#sql_sp"><SPAN CLASS="nowrap">sql_sp()</SPAN></A>. </P>
<P>When you pass a table-valued parameter to <A HREF="#sql"><SPAN CLASS="nowrap">sql()</SPAN></A>
and <A HREF="#sql_one"><SPAN CLASS="nowrap">sql_one()</SPAN></A>, you need to provide the type
name, but that&#39;s all. On the first time you present the table type,
Win32::SqlServer will retrieve the definition of the table type from <SMALL>SQL</SMALL> Server.
Win32::SqlServer saves  the definition in the property
<B><A HREF="#tabletypes">tabletypes</A></B>, and on future references to the type,
Win32::SqlServer will retrieve the
definition from the cache. Note that the cache is keyed by the string
exactly as you passed it, so <B>dbo.mytabletype</B>, <B>mytabletype</B> and <B>MyTableType</B> will be
three cache entries, even if they refer to the same type.</P>
<P>As you recall, <A HREF="#sql_sp"><SPAN CLASS="nowrap">sql_sp()</SPAN></A> retrieves the parameter profile for the stored procedure
from <SMALL>SQL</SMALL> Server or the Win32::SqlServer property <B><A HREF="#procs">procs</A></B>. When <A HREF="#sql_sp"><SPAN CLASS="nowrap">sql_sp()</SPAN></A> finds that a
parameter is a table, it will look up the type name in <B><A HREF="#tabletypes">tabletypes</A></B>, and if it is
absent, <A HREF="#sql_sp"><SPAN CLASS="nowrap">sql_sp()</SPAN></A> queries <SMALL>SQL</SMALL> Server for the definition and saves it in the cache.</P>
<P>To pass a value for a table-valued parameter, you pass a reference to an
   array of rows where each row is a hash or an array with the column values. It&#39;s
   perfectly possible to mix hashes and arrays in the same table array if you
   feel like it.
   </P>
   <P>When you pass row as a hash, the hash should be keyed by the column names
   (case-sensitive!). If you leave out a column, this is the same as specifying
   <CODE>undef</CODE> for the column, that is <SMALL>NULL</SMALL>; there is no way you can specify that you
   want any default value for a column to apply. If the hash includes a key
   that does not match a column in the table type, Win32::SqlServer emits a warning
   through the <A HREF="#MsgHandler">current message handler</A>, if Perl warnings are enabled. Likewise, Win32::SqlServer issues a warning if the hash includes a key for a column that is
   not writable, for instance an <SMALL>IDENTITY</SMALL> column or a
   computed column.</P>
   <P>When you pass a row as an array, you must pass the columns exactly in the
   order they come in the table definition. Even if a column is not writable
   (for instance an <SMALL>IDENTITY</SMALL> column), there still has to be an
   element in that slot, although it does not matter what you put there. You
   can pass an array with fewer elements than there are columns in the table
   type, in which case the columns missing from the array will be set to <SMALL>NULL</SMALL>.
   If your array has more columns than there are columns in the type,
   Win32::SqlServer issues a warning through the <A HREF="#MsgHandler">current
   message handler</A>, if Perl warnings are enabled.</P>
   <P>As for the column values, you pass the data types as you would in other
   contexts, see the section <A HREF="#datatypes">Data-type Representation</A>.</P>
   <P>To specify an empty table, you can pass <CODE>[]</CODE> or <CODE>undef</CODE>.
   With <A HREF="#sql_sp"><SPAN CLASS="nowrap">sql_sp()</SPAN></A>, you can leave out the parameter entirely.</P>
   <P><B>Confession</B>: there is unfortunately a considerable overhead for passing TVPs with Win32::SqlServer. In a test I conducted, it took around two seconds to pass 50000 rows for a one-column table. </P>
<P> Let&#39;s now look at some examples. In all examples we will
work with this type.</P>
<PRE>CREATE TYPE mytabletype AS TABLE
       (ident   int         IDENTITY,
        chr     char(1)     NOT NULL,
        intcol  int         NOT NULL,
        datecol date        NULL,
        string  varchar(40) NULL)        </PRE>
<P>Note: I&#39;m not sure that I see the point with an <SMALL>IDENTITY</SMALL> column in a
table-valued parameter. I have included one here to be able to demonstrate how
you work with non-writable columns.</P>
<P>Let&#39;s first look at using table types with stored procedures. Here is an
example procedure that you cannot accuse for being overly useful, but I wanted
to keep the examples brief.</P>
<PRE>CREATE PROCEDURE myproc @chr char(1),
                        @tvp mytabletype READONLY AS

SELECT totalcnt = COUNT(*),
       identsum = SUM(ident),
       chrcnt   = SUM(CASE chr WHEN @chr THEN 1 ELSE 0 END),
       datecnt  = SUM(CASE WHEN datecol IS NOT NULL THEN 1 ELSE 0 END),
       strcnt   = SUM(coalesce(len(string), 0))
FROM   @tvp</PRE>
<P>In the case when you set up the table rows in your own code, I think hashes
is the best choice. This makes
the code more readable, and it also makes it easier to leave out columns you
want to leave <SMALL>NULL</SMALL>. So in the first example, we pass the rows as hashes:</P>
<PRE>use strict;
use Win32::SqlServer;

my $sqlsrv = sql_init();

my @rows;

# Our first row. Here we provide all columns, but ident which we don&#39;t
# have control over anyway.
$rows[0]{&#39;chr&#39;}     = &#39;A&#39;;
$rows[0]{&#39;intcol&#39;}  = 14;
$rows[0]{&#39;datecol&#39;} = &#39;2009-01-01&#39;;
$rows[0]{&#39;string&#39;}  = &#39;Typewriter&#39;;

# Our second row. For this row, we leave out datecol and string.
$rows[1]{&#39;chr&#39;}    = &#39;B&#39;;
$rows[1]{&#39;intcol&#39;} = 9;

# Our third and foruth rows. By now we have realised that we can specify
# the entire hash at once:
$rows[2] = {&#39;chr&#39; =&gt; &#39;A&#39;, &#39;intcol&#39; =&gt; 5,  &#39;datecol&#39; =&gt; &#39;1632-11-06&#39;};
$rows[3] = {&#39;chr&#39; =&gt; &#39;C&#39;, &#39;intcol&#39; =&gt; 12, &#39;string&#39; =&gt; &#39;Luxury&#39;};

# Let&#39;s now call our procedure. We need to pass a reference to the array.
my %result = $sqlsrv-&gt;sql_sp(&#39;dbo.myproc&#39;, [&#39;A&#39;, \@rows],
                              Win32::SqlServer::SINGLEROW,
                              Win32::SqlServer::HASH);

# Output the result.
print &quot;totalcnt: $result{&#39;totalcnt&#39;}\n&quot;;
print &quot;identsum: $result{&#39;identsum&#39;}\n&quot;;
print &quot;chrcnt:   $result{&#39;chrcnt&#39;}\n&quot;;
print &quot;datecnt:  $result{&#39;datecnt&#39;}\n&quot;;
print &quot;strcnt:   $result{&#39;strcnt&#39;}\n&quot;;
</PRE>
<P>The output is:</P>
<PRE>totalcnt: 4
identsum: 10
chrcnt:   2
datecnt:  2
strcnt:   16</PRE>
<P>The way we filled in the rows in this example was somewhat tedious. Perl permits you to do this more compactly:</P>
<PRE>use strict;
use Win32::SqlServer;

my $sqlsrv = sql_init();

# Here define all rows at once in an array constructor.
my $rows = [{&#39;chr&#39; =&gt; &#39;A&#39;, &#39;intcol&#39; =&gt; 14, &#39;datecol&#39; =&gt; &#39;2009-01-01&#39;,
             &#39;string&#39; =&gt; &#39;Typewriter&#39;},
            {&#39;chr&#39; =&gt; &#39;B&#39;, &#39;intcol&#39; =&gt; 9},
            {&#39;chr&#39; =&gt; &#39;A&#39;, &#39;intcol&#39; =&gt; 5, &#39;datecol&#39; =&gt; &#39;1632-11-06&#39;},
            {&#39;chr&#39; =&gt; &#39;C&#39;, &#39;intcol&#39; =&gt; 12, &#39;string&#39; =&gt; &#39;Luxury&#39;}];

# This time we pass the parameters as named in a hash.
my %result = $sqlsrv-&gt;sql_sp(&#39;dbo.myproc&#39;, {chr =&gt; &#39;A&#39;, &#39;tvp&#39; =&gt; $rows},
                              Win32::SqlServer::SINGLEROW,
                              Win32::SqlServer::HASH);

# Output the result, same as above.
print &quot;totalcnt: $result{&#39;totalcnt&#39;}\n&quot;;
print &quot;identsum: $result{&#39;identsum&#39;}\n&quot;;
print &quot;chrcnt:   $result{&#39;chrcnt&#39;}\n&quot;;
print &quot;datecnt:  $result{&#39;datecnt&#39;}\n&quot;;
print &quot;strcnt:   $result{&#39;strcnt&#39;}\n&quot;;</PRE>
<P>Let&#39;s now look at how you pass the rows as
arrays instead. Arrays are probably mainly of interest when the table type has a
small number of columns, at least in the case you populate the rows yourself.</P>
<PRE>use strict;
use Win32::SqlServer;

my $sqlsrv = sql_init();

my @rows;

# The first row. We must include a placeholder for ident, since this is
# the first column.
push(@rows, [undef, &#39;A&#39;, 14, &#39;2009-01-01&#39;, &#39;Typewriter&#39;]);

# The second row. Since datecol and string are NULL, we can just leave
# them out.
push(@rows, [undef, &#39;B&#39;, 9]);

# The third row. What we specify for ident does not matter. It just has
# to be there.
push(@rows, [4711, &#39;A&#39;, 5, &#39;1632-11-06&#39;]);

# The fourth row. Since string has a value, we need to explicitly
# provide an undef for datecol.
push (@rows, [0, &#39;C&#39;, 12, undef, &#39;Luxury&#39;]);

my %result = $sqlsrv-&gt;sql_sp(&#39;dbo.myproc&#39;, {chr =&gt; &#39;A&#39;, &#39;tvp&#39; =&gt; \@rows},
                              Win32::SqlServer::SINGLEROW,
                              Win32::SqlServer::HASH);

# Output the result, same as before.
print &quot;totalcnt: $result{&#39;totalcnt&#39;}\n&quot;;
print &quot;identsum: $result{&#39;identsum&#39;}\n&quot;;
print &quot;chrcnt:   $result{&#39;chrcnt&#39;}\n&quot;;
print &quot;datecnt:  $result{&#39;datecnt&#39;}\n&quot;;
print &quot;strcnt:   $result{&#39;strcnt&#39;}\n&quot;;</PRE>
<P>Let&#39;s now look at examples where we use table-valued
parameters with <A HREF="#sql"><SPAN CLASS="nowrap">sql()</SPAN></A>. Here is the example with the hash rows again:</P>
<PRE>use strict;
use Win32::SqlServer;

my $sqlsrv = sql_init();

# It&#39;s the same old rows.
my $rows = [{&#39;chr&#39; =&gt; &#39;A&#39;, &#39;intcol&#39; =&gt; 14, &#39;datecol&#39; =&gt; &#39;2009-01-01&#39;,
             &#39;string&#39; =&gt; &#39;Typewriter&#39;},
            {&#39;chr&#39; =&gt; &#39;B&#39;, &#39;intcol&#39; =&gt; 9},
            {&#39;chr&#39; =&gt; &#39;A&#39;, &#39;intcol&#39; =&gt; 5, &#39;datecol&#39; =&gt; &#39;1632-11-06&#39;},
            {&#39;chr&#39; =&gt; &#39;C&#39;, &#39;intcol&#39; =&gt; 12, &#39;string&#39; =&gt; &#39;Luxury&#39;}];

# The SQL statement. It&#39;s the same as the body of the stored procedure.
# We put SQLEND in single quotes to protect the @ in the SQL variabels.
my $sqlcode = &lt;&lt;&#39;SQLEND&#39;;
   SELECT totalcnt = COUNT(*),
          identsum = SUM(ident),
          chrcnt   = SUM(CASE chr WHEN @chr THEN 1 ELSE 0 END),
          datecnt  = SUM(CASE WHEN datecol IS NOT NULL THEN 1 ELSE 0 END),
          strcnt   = SUM(coalesce(len(string), 0))
   FROM   @tvp
SQLEND

# Set up the parameter list. Since the batch uses named parameters, we need
# to specify the parameter list as a hash. First the character parameter.
my %params;
$params{&#39;@chr&#39;} = [&#39;char(1)&#39;, &#39;A&#39;];

# And then the table parameter. We can use the name of the table type directly
# sql() will look it up and find that it is a table type.
$params{&#39;@tvp&#39;} = [&#39;mytabletype&#39;, $rows];

# Now we call the batch.
my %result = $sqlsrv-&gt;sql($sqlcode, \%params,
                          Win32::SqlServer::SINGLEROW,
                          Win32::SqlServer::HASH);

# Output the same old result.
print &quot;totalcnt: $result{&#39;totalcnt&#39;}\n&quot;;
print &quot;identsum: $result{&#39;identsum&#39;}\n&quot;;
print &quot;chrcnt:   $result{&#39;chrcnt&#39;}\n&quot;;
print &quot;datecnt:  $result{&#39;datecnt&#39;}\n&quot;;
print &quot;strcnt:   $result{&#39;strcnt&#39;}\n&quot;;</PRE>
<P>Overall, I think named parameters is to prefer, and even more so when you
work with table-valued parameters. But if you want to work with positional
parameters, you can. Here is an example of this. This example also passes the
rows an array constructed in one go. Here we explicitly say that the parameter is a table, and pass the name of the table type as the third element in the array:</P>
<PRE>use strict;
use Win32::SqlServer;

my $sqlsrv = sql_init();

# The rows, now as arrays.
my $rows = [[undef, &#39;A&#39;, 14, &#39;2009-01-01&#39;, &#39;Typewriter&#39;],
            [undef, &#39;B&#39;, 9],
            [undef, &#39;A&#39;, 5, &#39;1632-11-06&#39;],
            [undef, &#39;C&#39;, 12, undef, &#39;Luxury&#39;]];

# The SQL statement. Now with positional parameters.
my $sqlcode = &lt;&lt;&#39;SQLEND&#39;;
   SELECT totalcnt = COUNT(*),
          identsum = SUM(ident),
          chrcnt   = SUM(CASE chr WHEN ? THEN 1 ELSE 0 END),
          datecnt  = SUM(CASE WHEN datecol IS NOT NULL THEN 1 ELSE 0 END),
          strcnt   = SUM(coalesce(len(string), 0))
   FROM   ?
SQLEND

# Now we call the batch. This time the parameters are in an anonymous array.
my %result = $sqlsrv-&gt;sql($sqlcode, [[&#39;char(1)&#39;, &#39;A&#39;],
                                     [&#39;table&#39;, $rows, 'dbo.mytabletype']],
                           Win32::SqlServer::SINGLEROW,
                           Win32::SqlServer::HASH);

# Output the result.
print &quot;totalcnt: $result{&#39;totalcnt&#39;}\n&quot;;
print &quot;identsum: $result{&#39;identsum&#39;}\n&quot;;
print &quot;chrcnt:   $result{&#39;chrcnt&#39;}\n&quot;;
print &quot;datecnt:  $result{&#39;datecnt&#39;}\n&quot;;
print &quot;strcnt:   $result{&#39;strcnt&#39;}\n&quot;;</PRE>
<P>In all these examples, I have put the rows for the table-valued
parameters in a separate variable. But if you want to show off, you can put it
all in the parameter list:</P>
<PRE>my %result = $sqlsrv-&gt;sql($sqlcode,
                          [[&#39;char(1)&#39;, &#39;A&#39;],
                           [&#39;dbo.mytabletype&#39;,
                              [[undef, &#39;A&#39;, 14, &#39;2009-01-01&#39;, &#39;Typewriter&#39;],
                               [undef, &#39;B&#39;, 9],
                               [undef, &#39;A&#39;, 5, &#39;1632-11-06&#39;],
                               [undef, &#39;C&#39;, 12, undef, &#39;Luxury&#39;]]]],
                           Win32::SqlServer::SINGLEROW,
                           Win32::SqlServer::HASH);</PRE>
<P>Or why not:</P>
<PRE>my %result = $sqlsrv-&gt;sql($sqlcode,
             {chr =&gt; [&#39;char(1)&#39;, &#39;A&#39;],
              tvp =&gt; [&#39;table(mytabletype)&#39;,
                [{&#39;chr&#39; =&gt; &#39;A&#39;, &#39;intcol&#39; =&gt; 14,
                  &#39;datecol&#39; =&gt; &#39;2009-01-01&#39;, &#39;string&#39; =&gt; &#39;Typewriter&#39;},
                 [undef, &#39;B&#39;, 9],
                 {&#39;chr&#39; =&gt; &#39;A&#39;, &#39;intcol&#39; =&gt; 5, &#39;datecol&#39; =&gt; &#39;1632-11-06&#39;},
                 {&#39;chr&#39; =&gt; &#39;C&#39;, &#39;intcol&#39; =&gt; 12, &#39;string&#39; =&gt; &#39;Luxury&#39;}]
                ]},
              Win32::SqlServer::SINGLEROW, Win32::SqlServer::HASH);</PRE>
<P>But don&#39;t blame me if you get lost in this orgy of nested brackets and
braces. This example has a third way of specifying the table type: <CODE><B>table</B></CODE> followed by the type name in parentheses.</P>
<P>We now change the first data row a bit:</P>
<PRE>{'ident' =&gt; 1, &#39;chr&#39; =&gt; &#39;A&#39;, &#39;intcol&#39; =&gt; 14, &#39;datecol&#39; =&gt; &#39;2009-01-01&#39;,
 &#39;stringcol&#39; =&gt; &#39;Typewriter&#39;}</PRE>
<P>That is, we have included the <SMALL>IDENTITY</SMALL> column, and we have
erred on one
column name. When we run this (assuming we specifed <SPAN CLASS="nowrap"><CODE>-w</CODE></SPAN>
that is!), we get these two warnings:</P>
<PRE>Message -1 from &#39;Win32::SqlServer&#39;, Severity: 10
Warning: input hash to inserttableparam includes key &#39;stringcol&#39;,
   but no such column has been defined for this table parameter.
Message from Win32::SqlServer at C:\temp\slask.pl line 34
Message -1 from &#39;Win32::SqlServer&#39;, Severity: 10
Warning: input hash to inserttableparam includes key &#39;ident&#39;,
   but this column has been defined with usedefault=1 and the value is ignored.
Message from Win32::SqlServer at C:\temp\slask.pl line 34</PRE>
<P>As these checks are performed by the mid-level interface, the error messages
are worded from that horizon. You will have to live with that. </P>
<P>Finally some examples on how to pass an empty table. All these are valid:</P>
<PRE>$sqlsrv-&gt;sql_sp(&#39;dbo.myproc&#39;, [&#39;A&#39;, [] ]);
$sqlsrv-&gt;sql_sp(&#39;dbo.myproc&#39;, [&#39;A&#39;, undef]);
$sqlsrv-&gt;sql_sp(&#39;dbo.myproc&#39;, [&#39;A&#39;]);</PRE>
<P>The last example works, because in <SMALL>SQL</SMALL> Server there is an implicit default
value of the empty table for all table-valued parameters. (On the other hand,
you are not permitted to pass <SMALL>NULL</SMALL> for table parameters, so when
Win32::SqlServer permits you to specify <CODE>undef</CODE> it bends the rules a bit.) For <A HREF="#sql"><SPAN CLASS="nowrap">sql()</SPAN></A>
you have these choices:</P>
<PRE>$sqlsrv-&gt;sql($sqlcode, {chr =&gt; [&#39;char(1)&#39;, &#39;A&#39;],
                        tvp =&gt; [&#39;mytabletype&#39;, [] ]});
$sqlsrv-&gt;sql($sqlcode, {chr =&gt; [&#39;char(1)&#39;, &#39;A&#39;],
                        tvp =&gt; [&#39;mytabletype&#39;, undef]});
$sqlsrv-&gt;sql($sqlcode, {chr =&gt; [&#39;char(1)&#39;, &#39;A&#39;],
                        tvp =&gt; [&#39;mytabletype&#39;]});</PRE>
<P>Since the batch does not compile if you don&#39;t define the parameter, you can&#39;t
escape it entirely.</P>
<H1><A NAME="Mid-level">Mid-Level Query Functions</A></H1>
<P>The high-level query functions are implemented in Perl, and they in their
   turn use the mid-level functions that are implemented in C++ (save for
 <A HREF="#get_result_sets"><SPAN CLASS="nowrap">get_result_sets()</SPAN></A>). In their turn they call the
   low-level functions in the <SMALL>OLE DB API</SMALL>, not exposed directly to Perl.</P>
<P>If you think that the high-level functions puts you too much into a
   straightjacket (or are just too bewildering for you), you can call the
   mid-level functions directly. But... there is a disclaimer: the extensive
   test suite for Win32::SqlServer does not include any tests of direct use of the mid-level functions. Thus, if your usage of these functions goes beyond what the
   high-level functions use, you are on somewhat less solid ground.</P>
<P>While the high-level functions presents the Win32::SqlServer as a stateless object by
   submitting the query and getting the result sets in one single call, the
   mid-level functions makes the Win32::SqlServer object very stateful, and there is a
   certain order in which you must call these functions:</P>
<TABLE>
<TR VALIGN="top"><TD>1.</TD><TD>
   First define the text of the command batch with
   <A HREF="#initbatch"><SPAN CLASS="nowrap">initbatch()</SPAN></A>.</TD></TR>
<TR VALIGN="top"><TD>2.</TD>
<TD>
For each parameter in the batch define the parameter with
      <A HREF="#enterparameter"><SPAN CLASS="nowrap">enterparameter()</SPAN></A>.</TD></TR>
<TR VALIGN="top"><TD>2a.</TD><TD>
   Define the columns of each table-valued parameter with
   <A HREF="#definetablecolumn"><SPAN CLASS="nowrap">definetablecolumn()</SPAN></A>, and populate the table parameters with <A HREF="#inserttableparam"><SPAN CLASS="nowrap">inserttableparam()</SPAN></A>. (You
   can do this once the table-parameter has been entered, or you can wait until
   all parameters have been entered.)</TD></TR>
<TR VALIGN="top"><TD>3.</TD><TD>
     Execute the command batch with <A HREF="#executebatch"><SPAN CLASS="nowrap">executebatch()</SPAN></A>.</TD></TR>
<TR VALIGN="top"><TD>4.</TD><TD>
     Iterate over all result sets with <A HREF="#nextresultset"><SPAN CLASS="nowrap">nextresultset()</SPAN></A>
       until this function returns a false value.</TD></TR>
<TR VALIGN="top"><TD>5.</TD>
<TD>
       Within a result set, iterate over all rows with <A HREF="#nextrow"><SPAN CLASS="nowrap">nextrow()</SPAN></A>
       until it returns false, alternatively skip the result set by calling
       <A HREF="#cancelresultset"><SPAN CLASS="nowrap">cancelresultset()</SPAN></A>. As long as
   you have not reached the end of the result set, you can retrieve column
   information with <A HREF="#getcolumninfo"><SPAN CLASS="nowrap">getcolumninfo()</SPAN></A>.</TD></TR>
<TR VALIGN="top"><TD>6.</TD><TD>
       When you have retrieved all result sets, get any output
       parameters from the command batch with <A HREF="#getoutputparams"><SPAN CLASS="nowrap">getoutputparams()</SPAN></A>.
       </TD></TR>
</TABLE>
<P>If all you need is more freedom when you specify the
   parameters, but you still want the result sets and the rows packaged
   according to row styles and result styles, you can perform steps 4 and 5 in
   one go by calling <A HREF="#get_result_sets"><SPAN CLASS="nowrap">get_result_sets()</SPAN></A>.</P>
<P>You cannot initiate a new command until you have retrieved all
   result sets and the output parameters, unless you first call
 <A HREF="#cancelbatch"><SPAN CLASS="nowrap">cancelbatch()</SPAN></A>. You can find out in which state you
   are by calling <A HREF="#getcmdstate"><SPAN CLASS="nowrap">getcmdstate()</SPAN></A>.</P>
<P>There are a couple of features in Win32::SqlServer that are not supported by the
   mid-level functions (because the code to implement them&nbsp; is in the <A HREF="#High-level">high-level query functions</A>). Here is a list of general restrictions:</P>
<UL>
   <LI>
      Logging of <SMALL>SQL</SMALL> statements with the <B><A HREF="#LogHandle">LogHandle</A></B> property is not performed.</LI>
   <LI>
      When you call a stored procedure with the <SMALL>ODBC</SMALL> call syntax, and there is an
      error, <A HREF="#ErrInfo"><SPAN CLASS="nowrap">sql_message_handler()</SPAN></A>, will print the batch as
      you submitted it. (With <A HREF="#sql_sp"><SPAN CLASS="nowrap">sql_sp()</SPAN></A>,
      Win32::SqlServer constructs an <SMALL>EXEC</SMALL>
      string for logging and error messages.)</LI>
   <LI>
      Errors in the use of parameters are not intercepted by
         Win32::SqlServer, but will be reported by <SMALL>SQL</SMALL> Server or the <SMALL>OLE DB</SMALL> provider.
      The messages from the latter can be very obscure. </LI>
   <LI>
      The <B><A HREF="#NoExec">NoExec</A></B> property has no effect.</LI>
   <LI>
      Conversions you have set up with <A HREF="#sql_set_conversion"><SPAN CLASS="nowrap">sql_set_conversion()</SPAN></A>
      have no effect (except in <A HREF="#get_result_sets"><SPAN CLASS="nowrap">get_result_sets()</SPAN></A>).</LI>
</UL>   <P>I list further restrictions with the function or parameter they apply to.</P>

<H2><A NAME="initbatch"><SPAN CLASS="nowrap">initbatch()</SPAN></A></H2>
<P>Defines the text for a command batch.</P>
<PRE>$sqlsrv-&gt;initbatch($batch)</PRE>
<DL>
   <DT><CODE>$batch</CODE></DT>
   <DD>The text for the batch. The batch can be parameterised, with parameters
   being indicated with <CODE>?</CODE> as placeholder. In
   difference to <A HREF="#sql"><SPAN CLASS="nowrap">sql()</SPAN></A>, names starting with <CODE>@</CODE> are
   not understood as parameters. (If you want to use named parameters, an
   alternative is to wrap the command batch in a call to <B>sp_executesql</B>.)
   See also below about
   <A HREF="#ODBCCall"><SMALL>ODBC</SMALL> call syntax</A>.
   </DD>
</DL>
   <P>Once you have called <A HREF="#initbatch"><SPAN CLASS="nowrap">initbatch()</SPAN></A>, you cannot call <A HREF="#initbatch"><SPAN CLASS="nowrap">initbatch()</SPAN></A> again until
      you have retrieved all result sets and the output parameters or cancelled
      the batch with <A HREF="#cancelbatch"><SPAN CLASS="nowrap">cancelbatch()</SPAN></A>.</P>
<P>As why you should parameterise your command in most cases, and when you
   should not, please see the subsections <A HREF="#whyparameter"><I>Why
   Parameterising <SMALL>SQL</SMALL> Commands at All?</I></A> and <I><A HREF="#whennotparameter">When
   You Should Not Parameterise</A></I> in the <A HREF="#sql"><SPAN CLASS="nowrap">sql()</SPAN></A> topic.</P>
<P>You do not have to be connected to call <A HREF="#initbatch"><SPAN CLASS="nowrap">initbatch()</SPAN></A>.</P>
<H3><A NAME="ODBCCall">Using ODBC Call Syntax</A></H3>
<P>To initiate a call of a stored procedure through <SMALL>RPC</SMALL>, use the <SMALL>ODBC</SMALL> call
   syntax, for instance:
   </P>
   <PRE>{? = call dbo.some_sp(?, ?)}</PRE>
<P>The first <CODE>?</CODE> is for the return value (which you can omit, if you
opt to ignore the return value), and the <CODE>?</CODE> in the parentheses
represent the parameters to the stored procedure. You should only supply as
many ? as you actually intend to provide. For instance, assume that <I>some_sp</I> actually
looks like this:</P>
<PRE>CREATE PROCEDURE some_sp @par1 int = 19,
                         @par2 char(2) = NULL,
                         @par3 datetime = NULL,
                         @par4 bit = 0 AS</PRE>
   You intend to provide a value only for <CODE><SPAN CLASS="nowrap">@par2</SPAN></CODE> and <CODE><SPAN CLASS="nowrap">@par4</SPAN></CODE>
when you call
   <A HREF="#enterparameter"><SPAN CLASS="nowrap">enterparameter()</SPAN></A>. In this case the parameter
list in the <SMALL>ODBC</SMALL> call should look like above, that is include two <CODE>?</CODE>
only.
<P>You can provide values directly in the command batch like this:</P>
   <PRE>{? = call dbo.some_sp(?, ?, ?, 1)}</PRE>
   <P>(But please only do this when you supply all parameters. I have no idea
      what happens if you leave out some.) You can also use named parameters:</P>
   <PRE>{? = call dbo.some_sp(@par2 = ?, @par4 = ?)}</PRE>
   <P><SMALL>OLE DB</SMALL> permits you to mix <SMALL>ODBC</SMALL> call syntax with regular commands, or to
      provide two calls for the same command batch. However, I have not tested
      this, nor analysed the ramifications of it. Be warned.</P>
<H2><A NAME="enterparameter"><SPAN CLASS="nowrap">enterparameter()</SPAN></A></H2>
<P>Defines a parameter for a parameterised command batch.</P>
<PRE>$ret = $sqlsrv-&gt;enterparameter($nameoftype, $maxlen, $paramname,
                               $isinput, $isoutput [, $value
                               [, $precision [, $scale [, $typeinfo]]]]);</PRE>
<DL>
<DT><CODE>$ret</CODE></DT>
<DD>
True if the parameter was entered successfully, false if not.</DD>
<DT>&nbsp;</DT>
<DT><CODE>$nameoftype</CODE></DT>
<DD>The name of the type, without any specification of length, precision etc.
That is, only <B><CODE>varchar</CODE></B>, not <B><CODE><SPAN CLASS="nowrap">varchar(3)</SPAN></CODE></B>.
This must be a system type; in difference to <A HREF="#sql"><SPAN CLASS="nowrap">sql()</SPAN></A>, you cannot use the name of a user-defined type created with <SMALL>CREATE TYPE</SMALL> or <B>sp_addtype</B>. The name must be the main name for the type; the name that appears in sys.types. You
  cannot use the data-type synonyms that ships with <SMALL>SQL</SMALL> Server. That is, you must use <CODE><B>int</B></CODE> and <CODE><B>char</B></CODE>, not <CODE><B>integer</B></CODE> or <B><CODE>character</CODE>. </B>There is one exception: you can use <B> <CODE>rowversion</CODE></B> for <B><CODE>timestamp</CODE></B>. For user-defined <SMALL>CLR </SMALL> types, use <B> <CODE>UDT</CODE></B>. For table types, use <CODE><B>table</B></CODE>. The name must be in lowercase, except for <B><CODE>UDT</CODE></B> which must be all uppercase. </DD>
<DT>&nbsp;</DT>
<DT><CODE>$maxlen</CODE></DT>
<DD>
<UL>
   <LI STYLE="margin-left: -20pt;">For regular-sized character and binary parameters to stored procedure,
specify the length of the parameter in the procedure definition. That is
   20 for <B><CODE><SPAN CLASS="nowrap">varchar(20)</SPAN></CODE></B> (as well as for
<B><CODE><SPAN CLASS="nowrap">nvarchar(20)</SPAN></CODE></B>; the length is not in bytes).
If you leave <CODE>$maxlen</CODE> as <CODE>undef</CODE>, you will get a default of 1, which is not likely
to be what you want.
   </LI>
   <LI  STYLE="margin-left: -20pt;">For character and binary parameters to ad-hoc batches,
   I recommend that you settle on a constant, and do not use the length of the
   current parameter value. This increases the cache reuse on the <SMALL>SQL</SMALL> Server
   side.</LI>
   <LI STYLE="margin-left: -20pt;">For large parameters, that is <B><CODE>(n)text</CODE></B>,
   <B><CODE>image</CODE></B>, the <B><CODE>(MAX)</CODE></B> types,
   <B><CODE>xml</CODE></B> and large UDTs, specify -1.
   </LI>
   <LI STYLE="margin-left: -20pt;">For <B><CODE>table</CODE></B>, this
parameter has a special meaning: <CODE>$maxlen</CODE> holds the number of columns in the
table type.
   </LI>
   <LI STYLE="margin-left: -20pt;">For data types with fixed length, you can set <CODE>$maxlen</CODE> to the size of
the data type or leave it <CODE>undef</CODE>.
   </LI>
</UL>
</DD>
<DT>&nbsp;</DT>
<DT><CODE>$paramname</CODE></DT>
<DD>The name for the parameter. This works differently depending on the context
where the parameter appears. This is something that is happening in the <SMALL>OLE
DB</SMALL> provider, not in Win32::SqlServer. From my investigations, I&#39;ve identified four
different cases.
<P><OL>
<LI>Parameters in regular <SMALL>SQL</SMALL> batch.</LI>
<LI><SMALL>ODBC</SMALL> Call Syntax &#8211; the return value.</LI>
<LI><SMALL>ODBC</SMALL> Call Syntax &#8211; named parameters, <CODE>{? = call some_sp(<SPAN CLASS="nowrap">@par3</SPAN> = ?)}</CODE>.</LI>
<LI><SMALL>ODBC</SMALL> Call Syntax – positional parameters, e.g. <CODE>{? = call some_sp(?,
   ?)}</CODE>.</LI>
</OL></P>
<P>The first three cases appear to behave the same, whereas the fourth is
   different.</P>
<P><B>Case 1-3</B> – you can set the parameter name to <CODE>undef</CODE>,
   or you can use whatever name you like, <I>as long as it starts with</I> <CODE>
   @</CODE>. (<B>Note</B>: for the return value in case 2, the <SMALL>SQLOLEDB</SMALL> provider
   will actually accept a name that does not start with <CODE>@</CODE>. But this
   is a bug! <SMALL>SQL</SMALL> Native Client never accepts names without <CODE>@</CODE> in
   front.) The name is never passed to <SMALL>SQL</SMALL> Server, but you can use it when you retrieve the value of an output parameter, see
   <A HREF="#getoutputparams"><SPAN CLASS="nowrap">getoutputparams()</SPAN></A>. For a regular <SMALL>SQL</SMALL> batch, the
   <SMALL>OLE DB</SMALL> provider will use names like <CODE><SPAN CLASS="nowrap">@P1</SPAN></CODE>,
   <CODE><SPAN CLASS="nowrap">@P2</SPAN></CODE> etc when it constructs the call to <B>sp_executesql</B>.</P>
   <P>
   <B>Case 4</B> – in this case, if you set the parameter name to <CODE>undef</CODE>
   for, say, the third <CODE>?</CODE>, this means that you pass a value for the
   second parameter. (Since the first <CODE>?</CODE> is the return value). If you specify a
   name, this must be the actual name of a parameter to the stored
   procedure.
   It appears that you can in fact mix named and unnamed parameters entirely
   here, and provide a name for the first parameter (that is, the second <CODE>?</CODE>),
   but leave it out for the second. I would not recommend this, though.</P></DD>

<DT><CODE>$isinput</CODE></DT>

<DD>1 if the parameter is an input parameter. Most parameters are input
parameters, but return values from stored procedures are not. Here is another
example of a parameter that is not an input parameter:
<PRE>SELECT ? = @@version</PRE>
</DD>
<DT><CODE>$isoutput</CODE></DT>
<DD>1 if the parameter is an output parameter. </DD>
<DT>&nbsp;</DT>
<DT><CODE>$value</CODE></DT>
<DD>The value for the parameter. You can leave this parameter out, if you are
passing <SMALL>NULL</SMALL>, or you have specified 0 for <CODE>$isinput</CODE>. If you
specified 1 for <CODE>$isinpu</CODE>t, Win32::SqlServer will attempt to convert the value to type
specified in <CODE>$nameoftype</CODE>, as described in the chapter
<A HREF="#datatypes">Data-type Representation</A>. If the parameter is a
table-valued parameter, you must specify <CODE>undef</CODE> for <CODE>$value</CODE>, or else
Win32::SqlServer will <CODE>croak</CODE>.</DD>
<DT>&nbsp;</DT>
<DT><CODE>$precision</CODE></DT>
<DT><CODE>$scale</CODE></DT>
<DD>Precision and scale for <B><CODE>decimal</CODE></B> and <CODE><B>numeric</B></CODE>.
If you don&#39;t specify these, the default values are 18 and 0 respectively.</DD>
<DT>&nbsp;</DT>
<DT><CODE>$typeinfo</CODE></DT>
<DD>This parameter applies only to parameters of the types <B><CODE>xml</CODE></B>,
<B><CODE>UDT</CODE></B> and <B><CODE>table</CODE></B>. For <B><CODE>xml</CODE></B>, it specifies a schema collection and is
optional. For <B><CODE>UDT</CODE></B> and <CODE><B>table</B></CODE>, it specifies the name of the actual <SMALL>CLR</SMALL>
type or table
type and is mandatory. All names can be specified with three-part notation on
the form <I>database</I>.<I>schema</I>.<I>object</I>. (Although, you may not
actually be able to specify a type in a different database.) If there are parts that
include special characters such as space or period, you must quote these in
brackets or double quotes. This parameter is not applicable when you use
<SMALL>SQLOLEDB</SMALL>. </DD>
</DL>
<P>You must call <A HREF="#initbatch"><SPAN CLASS="nowrap">initbatch()</SPAN></A> prior to calling
<A HREF="#enterparameter"><SPAN CLASS="nowrap">enterparameter()</SPAN></A>. You cannot call <A HREF="#enterparameter"><SPAN CLASS="nowrap">enterparameter()</SPAN></A>, once you have called
<A HREF="#executebatch"><SPAN CLASS="nowrap">executebatch()</SPAN></A>. You do not have to be connected when
you call <A HREF="#enterparameter"><SPAN CLASS="nowrap">enterparameter()</SPAN></A>.</P>
<P>If Win32::SqlServer cannot convert <CODE>$value</CODE> to <CODE>
   $nameoftype</CODE>, <A HREF="#enterparameter"><SPAN CLASS="nowrap">enterparameter()</SPAN></A> returns a false value. Once this has
   happened for a parameter, you will not be able to execute the batch with
   <A HREF="#executebatch"><SPAN CLASS="nowrap">executebatch()</SPAN></A>. Nevertheless, you can continue to
   enter more parameters. This makes it possible to catch all parameter errors in
   one go. Each parameter value that cannot be converted results in a warning
   communicated through the <A HREF="#MsgHandler">current message handler</A>..</P>
<P>You must call <A HREF="#enterparameter"><SPAN CLASS="nowrap">enterparameter()</SPAN></A> exactly as many times as there are parameter
   holders in your command batch. Specifying too many parameters, will yield the
   message <I>Multiple-step <SMALL>OLE DB</SMALL> operation generated errors</I>. But
   this is a generic message and can appear in other situations as well. </P>
<P>If any of the parameters is a table-valued parameter, you must define the
columns in the table type by calling <A HREF="#definetablecolumn"><SPAN CLASS="nowrap">definetablecolumn()</SPAN></A> for each column. You
then enter rows with <A HREF="#inserttableparam"><SPAN CLASS="nowrap">inserttableparam()</SPAN></A>.</P>
<P>Note that far from all parameter errors are detected by <A HREF="#enterparameter"><SPAN CLASS="nowrap">enterparameter()</SPAN></A>, but
   will not raise an error message until you call
   <A HREF="#executebatch"><SPAN CLASS="nowrap">executebatch()</SPAN></A>, for instance an illegal parameter
   name.</P>
<H2><A NAME="definetablecolumn"><SPAN CLASS="nowrap">definetablecolumn()</SPAN></A></H2>
<P>Defines a column in a table-variable parameter previously entered with
<A HREF="#enterparameter"><SPAN CLASS="nowrap">enterparameter()</SPAN></A>.</P>
<PRE>$ret = $sqlsrv-&gt;definetablecolumn($tblname, $colname, $nameoftype
                                  [, $maxlen&nbsp;[, $prec, [, $scale
                                  [, $usedefault [, $typeinfo]]]]]);</PRE>
<DL>
   <DT><CODE>$ret</CODE> </DT>
   <DD>True if the call completed successfully, else false.</DD>
   <DT>&nbsp;</DT>
   <DT><CODE>$tblname</CODE></DT>
   <DD>The name of the table-valued parameter for which you are defining a
   column. This is the name you specified in the <CODE>$paramname</CODE> parameter to
   <A HREF="#enterparameter"><SPAN CLASS="nowrap">enterparameter()</SPAN></A>. If you leave <CODE>$tblname</CODE> as <CODE>undef</CODE>,
   this is understood as the most recently entered parameter, even if this is
   not a table parameter. Thus, if you work with unamed parameters, you must
   define your table columns and insert your rows directly after you have
   entered the parameter. If the parameter <CODE>$tblname</CODE> refer to is
   not a table parameter, <A HREF="#definetablecolumn"><SPAN CLASS="nowrap">definetablecolumn()</SPAN></A> will <CODE>croak</CODE>.</DD>
   <DT>&nbsp;</DT>
   <DT><CODE>$colname</CODE></DT>
   <DD>The name of the column. You don&#39;t have to use the actual names in the
   table type, although it&#39;s best practice to do so. If you pass rows as hashes
   to <A HREF="#inserttableparam"><SPAN CLASS="nowrap">inserttableparam()</SPAN></A>, the names you use in <CODE>$colname</CODE> will be your hash keys.</DD>
   <DT>&nbsp;</DT>
   <DT><CODE>$nameoftype</CODE></DT>
   <DD>The data type for the parameter. The same rules as for <A HREF="#enterparameter"><SPAN CLASS="nowrap">enterparameter()</SPAN></A>
   apply. That is, you must use the system names, and you should not include
   length or similar. Not surprisingly, the type <CODE><B>table</B></CODE> is
   not permitted here, but all other types are legit.</DD>
   <DT>&nbsp;</DT>
   <DT><CODE>$maxlen</CODE></DT>
   <DD>Maximum length for character and binary data types (including <CODE><B>
   UDT</B></CODE>).&nbsp;For large data types, that is <B><CODE>(n)text</CODE></B>, <B><CODE>image</CODE></B>, the
<B><CODE>(MAX)</CODE></B>
types and <B><CODE>xml</CODE></B>, specify -1. The length is in characters, not
   bytes, so specify 20 for <CODE><B><SPAN CLASS="nowrap">nvarchar(20)</SPAN></B></CODE>.</DD>
<DT>&nbsp;</DT>
  <DT><CODE>$precision</CODE></DT>
<DT><CODE>$scale</CODE></DT>
<DD>Precision and scale for <B><CODE>decimal</CODE></B> and <CODE><B>numeric</B></CODE>.
If you don&#39;t specify these, the default values are 18 and 0 respectively.</DD>
   <DT>&nbsp;</DT>
   <DT><CODE>$usedefault</CODE></DT>
   <DD>This is a boolean parameter with a default value of false. When true,
   this specifies that the default value for this column should apply to <I>all
   rows</I> inserted into the table-valued parameter. You must set <CODE>$usedefault</CODE>
   to true for columns that cannot be set explicitly: <SMALL>IDENTITY</SMALL> columns,
   timestamp/rowversion columns and computed columns.</DD>
   <DT>&nbsp;</DT>
   <DT><CODE>$typeinfo</CODE></DT>
   <DD>Type information for <CODE><B>xml</B></CODE> and <CODE><B>UDT</B></CODE>
   columns, in the same vein as for <A HREF="#enterparameter"><SPAN CLASS="nowrap">enterparameter()</SPAN></A>.</DD>
</DL>
<P>You should call <A HREF="#definetablecolumn"><SPAN CLASS="nowrap">definetablecolumn()</SPAN></A> once for column in the table type. You need
to define the columns in the order they are defined in the table type. You cannot
define the fifth column first etc.</P>
<P>You specify the number of columns in the table type with the <CODE>$maxlen</CODE>
parameter to <A HREF="#enterparameter"><SPAN CLASS="nowrap">enterparameter()</SPAN></A>. Once you have defined that many columns, you can
start entering rows with <A HREF="#inserttableparam"><SPAN CLASS="nowrap">inserttableparam()</SPAN></A>.</P>
<H2><A NAME="inserttableparam"><SPAN CLASS="nowrap">inserttableparam()</SPAN></A></H2>
<P>Inserts one row into a table-valued parameter.</P>
<PRE>$ret = $sqlsrv-&gt;inserttableparm($tblname, $inputref);</PRE>
<DL>
   <DT><CODE>$ret</CODE></DT>
   <DD>Returns true if the row was inserted successfully, and all values were
   convertible. False, if one or more values were not convertible to the <SMALL>SQL</SMALL>
   type in question.</DD>
   <DT>&nbsp;</DT>
   <DT><CODE>$tblname</CODE></DT>
   <DD>The name of the table-valued parameter you are insert a row into. This
   is the name you specified in the <CODE>$paramname</CODE> to <A HREF="#enterparameter"><SPAN CLASS="nowrap">enterparameter()</SPAN></A>. As with
   <A HREF="#definetablecolumn"><SPAN CLASS="nowrap">definetablecolumn()</SPAN></A>, <CODE>undef</CODE> refers to the most recently entered parameter,
   even if this is not a table parameter.</DD>
   <DT>&nbsp;</DT>
   <DT><CODE>$inputref</CODE></DT>
   <DD>A reference to a hash or an array of column values for the row. See
   below for details.</DD>
</DL>
<P>Before you can call <A HREF="#inserttableparam"><SPAN CLASS="nowrap">inserttableparam()</SPAN></A> for a table-valued parameter, you should have called <A HREF="#definetablecolumn"><SPAN CLASS="nowrap">definetablecolumn()</SPAN></A> for all columns in the table type.</P>
<P>When you provide the values in a hash, the hash should be keyed with the
names you used when you set up the table type with <A HREF="#definetablecolumn"><SPAN CLASS="nowrap">definetablecolumn()</SPAN></A>. If you
leave out a column, that column is simply set to <SMALL>NULL</SMALL>. If your hash includes a
key that does not match a column in the table, <A HREF="#inserttableparam"><SPAN CLASS="nowrap">inserttableparam()</SPAN></A> will emit a
warning if Perl warnings are enabled. <A HREF="#inserttableparam"><SPAN CLASS="nowrap">inserttableparam()</SPAN></A> will also give a warning,
if you specify a value for a column for which you have specified <CODE>$usedefault</CODE> =
1.</P>
<P>When you provide the values in an array, the values should appear in the
order they appear in the table definition, <I>including</I> columns with
<CODE>$usedefault</CODE> = 1, even if the values you provide will be ignored. If your array
has fewer elements than the table type, the last columns will be set to <SMALL>NULL</SMALL>. If
your array has more elements than there are columns in the table type,
<A HREF="#inserttableparam"><SPAN CLASS="nowrap">inserttableparam()</SPAN></A> will issue a warning, if Perl warnings are enabled.</P>
<P>As with <A HREF="#enterparameter"><SPAN CLASS="nowrap">enterparameter()</SPAN></A>, if a value fails to convert, this only yields a
warning at this point, but when you call <A HREF="#executebatch"><SPAN CLASS="nowrap">executebatch()</SPAN></A>, there will be an error
and the batch will not be executed. This permits you to detect all parameter
errors in one go.</P>
<H2><A NAME="executebatch"><SPAN CLASS="nowrap">executebatch()</SPAN></A></H2>
<P>Executes a batch previously defined with <A HREF="#initbatch"><SPAN CLASS="nowrap">initbatch()</SPAN></A>.</P>
<PRE>$ret = $sqlsrv-&gt;executebatch();</PRE>
<DL>
   <DT><CODE>$ret</CODE></DT>
   <DD>True if the command batch was successfully submitted for execution, else
   false.</DD>
</DL>
<P>You must first define a command batch with <A HREF="#initbatch"><SPAN CLASS="nowrap">initbatch()</SPAN></A> and  enter definitions for all parameters to the batch before you can call <A HREF="#executebatch"><SPAN CLASS="nowrap">executebatch()</SPAN></A>. Once you have executed the command batch, you cannot resubmit
the command. When you call <A HREF="#executebatch"><SPAN CLASS="nowrap">executebatch()</SPAN></A>, you must be connected, unless you have
set the <B><A HREF="#AutoConnect">AutoConnect</A></B> property. In the latter
case, <A HREF="#executebatch"><SPAN CLASS="nowrap">executebatch()</SPAN></A> will connect automatically.
</P>
<P>If you entered a table-valued parameter with <A HREF="#enterparameter"><SPAN CLASS="nowrap">enterparameter()</SPAN></A>, but you did not
define as many columns as you defined with the <CODE>$maxlen</CODE> parameter, <A HREF="#executebatch"><SPAN CLASS="nowrap">executebatch()</SPAN></A>
will <CODE>croak</CODE>.</P>
<P>Note that the return status reports whether the submission of the batch was
   successful. That is, errors you get at this point are those detected by
   Win32::SqlServer and the <SMALL>OLE DB</SMALL> provider. Errors from <SMALL>SQL</SMALL> Server are not reported until
   you call <A HREF="#nextresultset"><SPAN CLASS="nowrap">nextresultset()</SPAN></A>. (And if your batch
   returns result sets before the error, you will not see the error until you
   have called <A HREF="#nextresultset"><SPAN CLASS="nowrap">nextresultset()</SPAN></A> for
these result
   sets.) If the command submission fails, the batch is cancelled, and you
   cannot perform any further work with it.</P>
<P>Most errors are communicated through the <A HREF="#MsgHandler">current
   message handler</A>, but pure usage errors like calling <A HREF="#executebatch"><SPAN CLASS="nowrap">executebatch()</SPAN></A> without
   being connected, causes Win32::SqlServer to <CODE>croak</CODE>.</P>
<H2><A NAME="nextresultset"><SPAN CLASS="nowrap">nextresultset()</SPAN></A></H2>
<P>Moves on to the next result set from the command batch.</P>
<PRE>$more_results = $sqlsrv-&gt;nextresultset([$rowsaffected});</PRE>
<DL>
   <DT><CODE>$more_results</CODE></DT>
   <DD>True if there was indeed a result set. False if there were no more result
   sets.</DD>
   <DT>&nbsp;</DT>
   <DT><CODE>$rowsaffected</CODE></DT>
   <DD>An optional output parameter that reports the number of affected rows for
   an <SMALL>INSERT, DELETE</SMALL> or <SMALL>UPDATE</SMALL>
   statement. You don&#39;t get any row counts if <SMALL>SET NOCOUNT ON</SMALL>
   is in effect</DD>
</DL>
<P>You can only call <A HREF="#nextresultset"><SPAN CLASS="nowrap">nextresultset()</SPAN></A>, if you previously have successfully
   submitted a command batch with <A HREF="#executebatch"><SPAN CLASS="nowrap">executebatch()</SPAN></A>.
   You cannot call <A HREF="#nextresultset"><SPAN CLASS="nowrap">nextresultset()</SPAN></A>, if there are more rows to retrieve from the
   current result set. You must either iterate over <A HREF="#nextrow"><SPAN CLASS="nowrap">nextrow()</SPAN></A>
   until this function returns false, or discard the rows with <A HREF="#cancelresultset"><SPAN CLASS="nowrap">cancelresultset()</SPAN></A> to be
   able to move to the next result set. </P>
<P>For each command batch you will need to call <A HREF="#nextresultset"><SPAN CLASS="nowrap">nextresultset()</SPAN></A> at least twice.
   First once to move to the first result set which is always there, even if there
   are no rows. And then a second time to move past the last result set.
   It is first at this point that output parameters will be available. Once
   <A HREF="#nextresultset"><SPAN CLASS="nowrap">nextresultset()</SPAN></A> have returned false, you cannot call <A HREF="#nextresultset"><SPAN CLASS="nowrap">nextresultset()</SPAN></A>
again for the current command batch. </P>
<P>Not all result sets have rows. Errors and other messages from <SMALL>SQL</SMALL> Server also
   yield a &quot;result set&quot;, as does the row count from <SMALL>INSERT,
   UPDATE</SMALL> and <SMALL>DELETE</SMALL> statements. And
   there are entirely empty result sets. For result sets of
   this kind, you can move on the next result set directly without calling
   <A HREF="#nextrow"><SPAN CLASS="nowrap">nextrow()</SPAN></A>. But if you want to play safe, always enter a loop
   over <A HREF="#nextrow"><SPAN CLASS="nowrap">nextrow()</SPAN></A>.</P>
<P>If the command batch results in <SMALL>SQL</SMALL> errors, they are communicated through the
   <A HREF="#MsgHandler">current message handler</A> when you call
   <A HREF="#nextresultset"><SPAN CLASS="nowrap">nextresultset()</SPAN></A>. Note that if a batch returns several result sets, an error
   is not reported until you have retrieved previous result sets. Consider this
   batch.</P>
<PRE>SET NOCOUNT OFF
UPDATE tbl SET ... WHERE
INSERT tbl (...) VALUES ...
SELECT @@identity
DELETE tbl2 WHERE ...</PRE>
Assume now that the <SMALL>DELETE</SMALL> statement causes a foreign-key
violation. This will not be reported until you call <A HREF="#nextresultset"><SPAN CLASS="nowrap">nextresultset()</SPAN></A> the fourth
time. The two first result sets will bring you the row counts from the
<SMALL>UPDATE</SMALL> and <SMALL>INSERT</SMALL> statements, the third the value of <CODE>
<SPAN CLASS="nowrap">@@identity</SPAN></CODE>.
<H2><A NAME="nextrow"><SPAN CLASS="nowrap">nextrow()</SPAN></A></H2>
<P>Retrieves the next row from the current result set.</P>
<PRE>$more_rows = $sqlsrv-&gt;nextrow($hashref, $arrayref);</PRE>
<DL>
   <DT><CODE>$more_rows</CODE></DT>
   <DD>True, if a row was returned, and there may be more rows. False means
   that no row was returned, because you have reached the end of the result set.</DD>
   <DT>&nbsp;</DT>
   <DT><CODE>$hashref</CODE></DT>
   <DD>A scalar variable that on output receives the reference to a hash that
   holds the data for the row. The keys in the hash are the column names. For
   nameless columns, you get <I>Col 1</I>, <I>Col 2</I> etc. Note that you must
   pass a scalar variable. Passing a reference to a hash on the form <CODE>
   <SPAN CLASS="nowrap">\%hash</SPAN></CODE> won&#39;t do. If you don&#39;t care about the hash, you
   can pass <CODE>undef</CODE>.</DD>
   <DT>&nbsp;</DT>
   <DT><CODE>$arrayref</CODE></DT>

   <DD>A scalar variable that on output receives the reference to an array that
   holds the data for the row. As for <CODE>$hashref</CODE>, you must pass a scalar,
   <CODE><SPAN CLASS="nowrap">\@array</SPAN></CODE> will not work. If you don&#39;t care about the
   array, pass <CODE>undef</CODE>. You cannot omit the parameter. </DD>
</DL>
<P>
You can only call <A HREF="#nextrow"><SPAN CLASS="nowrap">nextrow()</SPAN></A> when you have an active result set, that is you have
previously called <A HREF="#nextresultset"><SPAN CLASS="nowrap">nextresultset()</SPAN></A> and you have
not yet reached the end of that
result set. Once <A HREF="#nextrow"><SPAN CLASS="nowrap">nextrow()</SPAN></A> has returned false, you cannot call <A HREF="#nextrow"><SPAN CLASS="nowrap">nextrow()</SPAN></A> again,
until you have advanced to the next result set.</P>
<P>As noted under
   <A HREF="#nextresultset"><SPAN CLASS="nowrap">nextresultset()</SPAN></A>, some result sets convey other information than rows from
   queries. You can still call <A HREF="#nextrow"><SPAN CLASS="nowrap">nextrow()</SPAN></A> once for these result sets.</P>
<H2><A NAME="getcolumninfo"><SPAN CLASS="nowrap">getcolumninfo()</SPAN></A></H2>
<P>Retrieves information about the columns in the current result set.</P>
<PRE>$sqlsrv-&gt;getcolumnnames($hashref, $arrayref)</PRE>
<DL>
   <DT><CODE>$hashref</CODE></DT>
   <DD>A scalar variable that on output receives the reference to a hash that
   holds the column information as detailed below. The keys in <SPAN CLASS="nowrap"><CODE>%$hashref</CODE></SPAN> are
   the column names in the query. As with <A HREF="#nextrow"><SPAN CLASS="nowrap">nextrow()</SPAN></A>, you get <I>Col 1</I>, <I>Col 2</I>
   etc for nameless columns. You must pass a scalar variable, <SPAN CLASS="nowrap"><CODE>\%hash</CODE></SPAN>
   will not work. If you don&#39;t care about the hash, you
   can pass <CODE>undef</CODE>.</DD>
   <DT>&nbsp;</DT>
   <DT><CODE>$arrayref</CODE></DT>

   <DD>A scalar variable that on output receives the reference to an array that
   holds the column information as detailed below. The value of each array entry
   is a reference to a hash&nbsp; with the keys detailed below. As for <CODE>$hashref</CODE>, you
   must pass a scalar; you cannot pass <CODE><SPAN CLASS="nowrap">\@array</SPAN></CODE>. If you don&#39;t care about the
   array, pass <CODE>undef</CODE>. You cannot omit the parameter. </DD>
</DL>
<P>You can call <A HREF="#getcolumninfo"><SPAN CLASS="nowrap">getcolumninfo()</SPAN></A> exactly in the same situations you can call
<A HREF="#nextrow"><SPAN CLASS="nowrap">nextrow()</SPAN></A>. That is, you must previously have called <A HREF="#nextresultset"><SPAN CLASS="nowrap">nextresultset()</SPAN></A> and <A HREF="#nextrow"><SPAN CLASS="nowrap">nextrow()</SPAN></A>
has not yet returned false. Some result sets conveys row counts, and have no
column information. For these result
sets <SPAN CLASS="nowrap"><CODE>%$hashref</CODE></SPAN> and <SPAN CLASS="nowrap"><CODE>@$arrayref</CODE></SPAN> will be empty.</P>
<P>For each column you get a hash with eight keys:</P>
<DL>
   <DT><B>Colno</B></DT>
   <DD>The position of the column in the result set; the first column has
   number 1.</DD>
   <DT>&nbsp;</DT>
   <DT><B>Name</B></DT>
   <DD>The name of the column. Note that this is the name of the column as
   returned by <SMALL>SQL</SMALL> Server. That is, a nameless column will here appears as the
   empty string, not <I>Col 1</I> as when then column name appears as a hash
   key.</DD>
   <DT>&nbsp;</DT>
   <DT><B>Type</B></DT>
   <DD>The data type of the column. The type names that appear are the main
   names used in the system catalogue. That is, always <CODE><B>int</B></CODE>
   and <CODE><B>timestamp</B></CODE>, never <CODE><B>integer</B></CODE> and
   <CODE><B>rowversion</B></CODE>, nor the names of any user-defined data
   types. Furthermore, any column of the type <CODE><B>numeric</B></CODE>
   appears as <CODE><B>decimal</B></CODE>. The types <CODE><B>text</B></CODE>,
   <CODE><B>ntext</B></CODE> and <CODE><B>image</B></CODE> appear as <CODE><B>
   varchar</B></CODE>, <CODE><B>nvarchar</B></CODE> and <CODE><B>varbinary</B></CODE>
   respectively,
   with <B>Maxlength</B> set to <CODE>undef</CODE>. A <SMALL>CLR</SMALL> type appears as <CODE>
   <B>UDT</B></CODE>; the actual name of the type is not available. This applies
   to both user-defined <SMALL>CLR</SMALL> types and built-in <SMALL>CLR</SMALL> types.</DD>
   <DT>&nbsp;</DT>
   <DT><B>Maxlength</B></DT>
   <DD>The maximum length for the column. Mainly relevant for character and
   binary data types, but <SMALL>SQL</SMALL> Server appears to populate it for other types as
   well. <B>Maxlength</B> is <CODE>undef</CODE> for large data types as well for types where it is
   not applicable.</DD>
   <DT>&nbsp;</DT>
   <DT><B>Precision</B></DT>
   <DD>The precision for the column. Mainly relevant for <B><CODE>decimal</CODE></B> and <B><CODE>numeric</CODE></B> ,
       but <SMALL>SQL</SMALL> Server appears to populate it for other types as well. <B>
   Precision</B> is <CODE>undef</CODE> for types
       where it is not applicable.</DD>
   <DT>&nbsp;</DT>
   <DT><B>Scale</B></DT>
   <DD>The scale for the column. Relevant for <B><CODE>decimal</CODE></B>, <B><CODE>numeric</CODE></B>, <CODE><B>time</B></CODE>, <B><CODE>datetime2</CODE></B> and <B><CODE>datetimeoffset</CODE></B>. <B>Scale</B> is <CODE>undef</CODE> for types where it is not applicable.</DD>
   <DT>&nbsp;</DT>
   <DT><B>Maybenull</B></DT>
   <DD>1 if there may be <SMALL>NULL</SMALL> values in the column, 0 if <SMALL>NULL</SMALL> values cannot appear.</DD>
   <DT>&nbsp;</DT>
   <DT><B>Readonly</B></DT>
   <DD>Reflects whether <SMALL>SQL</SMALL> Server thinks it is permissible to update this
   column directly in the rowset. Since you don&#39;t operate on the rowset
   directly anyway with Win32::SqlServer, this piece of information is of esoteric interest. But if you ever worked with <SMALL>ADO</SMALL>, and received&nbsp;
   a weird error when you tried to update a field in a recordset, it probably
   was because the column was read-only.</DD>
</DL>
<P>Note that the column-information hash is <I>not</I> a tied hash. Thus, misspelling of
any of the
hash keys will go unnoticed.</P>
<H2><A NAME="get_result_sets"><SPAN CLASS="nowrap">get_result_sets()</SPAN></A></H2>
<P>
Retrieves all result sets and rows for a command batch, and returns them on the
specified form.</P>
<PRE>($|@|%)result = $sqlsrv-&gt;get_result_sets([$colinfostyle][, $rowstyle]
                                         [, $resultstyle] [\@keys]);</PRE>
<DL>
   <DT><CODE>($|@|%)result</CODE></DT>
   <DD>The result set(s) from the command batch. Depending on the <CODE>
   $rowstyle</CODE> and
   <CODE>$resultstyle</CODE> parameters, this can be an array, a hash or a scalar.
   If the result is an array or a hash, you can always use a scalar to receive
   the return value as a reference to the array/hash. </DD>
   <DT>&nbsp;</DT>
   <DT><CODE>$colinfostyle</CODE></DT>
   <DD>Specifies if and how you want information about the columns in the
   result set(s). Possible values are <A HREF="#COLINFO_NONE"><SMALL>COLINFO_NONE</SMALL></A> (no information),
   <A HREF="#COLINFO_NAMES"><SMALL>COLINFO_NAMES</SMALL></A> (names only), <A HREF="#COLINFO_POS"><SMALL>COLINFO_POS</SMALL></A> (column numbers only) and
   <A HREF="#COLINFO_FULL"><SMALL>COLINFO_FULL</SMALL></A> (a hash with detailed information about the columns). See the
   section <A HREF="#colinfostyles">Getting Column Information</A> in the
   description of <A HREF="#sql"><SPAN CLASS="nowrap">sql()</SPAN></A> for details. The default is <A HREF="#COLINFO_NONE"><SMALL>COLINFO_NONE</SMALL></A>.</DD>
   <DT>&nbsp;</DT>
   <DT><CODE>$rowstyle</CODE></DT>
   <DD>How rows are represented in the result set. Can be <A HREF="#HASH"><SMALL>HASH</SMALL></A> (the
      default), <A HREF="#LIST"><SMALL>LIST</SMALL></A> (to get an array) or <A HREF="#SCALAR"><SMALL>SCALAR</SMALL></A>. See the section
      <A HREF="#RowResultStyles">Row Styles and Result Styles</A> in the
      description of <A HREF="#sql"><SPAN CLASS="nowrap">sql()</SPAN></A> for details.</DD>
   <DT>&nbsp;</DT>
   <DT><CODE>$resultstyle</CODE></DT>
   <DD>Specifies how the result sets are to be structured. Possible values are
   <A HREF="#MULTISET"><SMALL>MULTISET</SMALL></A> (an array of result sets),
   <A HREF="#MULTISET_RC"><SMALL>MULTISET_RC</SMALL></A> (an array of result sets and row counts for action statements), <A HREF="#SINGLESET"><SMALL>SINGLESET</SMALL></A> (an array of rows), <A HREF="#SINGLEROW"><SMALL>SINGLEROW</SMALL></A>
   (a single row according to <CODE>$rowstyle</CODE>), <A HREF="#KEYED"><SMALL>KEYED</SMALL></A> (a hash, keyed by
   the data in the result set), <A HREF="#NORESULT"><SMALL>NORESULT</SMALL></A> (no result set returned) or a reference
   to a callback routine that is called on each row. See the section
   <A HREF="#RowResultStyles">Row Styles and Result Styles</A> in the
   description for <A HREF="#sql"><SPAN CLASS="nowrap">sql()</SPAN></A> for details. Default is <A HREF="#SINGLESET"><SMALL>SINGLESET</SMALL></A>.</DD>
   <DT>&nbsp;</DT>
   <DT><CODE>\@keys</CODE></DT>
   <DD>This parameter is only applicable when <CODE>$resultstyle</CODE> is
   <A HREF="#KEYED"><SMALL>KEYED</SMALL></A>, in which case it&#39;s mandatory. It specifies which column(s) in the
   result that is/are the keys.</DD>
</DL>
<P>
You can only call <A HREF="#get_result_sets"><SPAN CLASS="nowrap">get_result_sets()</SPAN></A> when you have executed a command batch with
<A HREF="#executebatch"><SPAN CLASS="nowrap">executebatch()</SPAN></A>. When <A HREF="#get_result_sets"><SPAN CLASS="nowrap">get_result_sets()</SPAN></A> have completed, you can go on and fetch
output parameters with <A HREF="#getoutputparams"><SPAN CLASS="nowrap">getoutputparams()</SPAN></A>. If there are no output parameters,
 all resources allocated for the batch are released, and Win32::SqlServer is ready to
accept a new call to <A HREF="#initbatch"><SPAN CLASS="nowrap">initbatch()</SPAN></A> or a
<A HREF="#High-level">high-level query function</A>.</P>
<P>
<A HREF="#get_result_sets"><SPAN CLASS="nowrap">get_result_sets()</SPAN></A> is in fact the inner part of <A HREF="#sql"><SPAN CLASS="nowrap">sql()</SPAN></A>
and <A HREF="#sql_sp"><SPAN CLASS="nowrap">sql_sp()</SPAN></A>, and
the return value and the style parameters works exactly as for these two. See
the sections <A HREF="#RowResultStyles">Row Styles and Result Styles</A> and
<A HREF="#colinfostyles">Getting Column Information</A> in the
topic of <A HREF="#sql"><SPAN CLASS="nowrap">sql()</SPAN></A> for details.</P>
<H2><A NAME="getoutputparams"><SPAN CLASS="nowrap">getoutputparams()</SPAN></A></H2>
<P>Retrieves the output parameters from a command batch.</P>
<PRE>$sqlsrv-&gt;getoutputparams($hashref, $arrayref);</PRE>
<DL>
   <DT><CODE>$hashref</CODE></DT>
   <DD>A scalar variable that on output receives a reference to a hash. The keys
   in the hash are the parameter names (don&#39;t forget the leading <CODE>@</CODE>)
   you provided with <A HREF="#enterparameter"><SPAN CLASS="nowrap">enterparameter()</SPAN></A>. For parameters for which you passed <CODE>undef</CODE>
   for the name, the keys are <I>Par 1, Par 2</I> etc (without any <CODE>@</CODE>.)
   You must pass a scalar, you cannot pass a reference to hash like <CODE><SPAN CLASS="nowrap">
   \%hash</SPAN></CODE>. You can pass <CODE>undef</CODE> if you don&#39;t care about
   the hash.</DD>
   <DT>&nbsp;</DT>
   <DT><CODE>$arrayref</CODE></DT>
   <DD>A scalar variable that on output, receives a reference to an array. The
   output parameters appear in the array in the order you defined them. There
   are no empty slots for input-only parameters. That is, if you enter
   nine parameters, and parameters 2, 7 and 9 are output parameters, they will
   appear at <CODE><SPAN CLASS="nowrap">$$arrayref[0]</SPAN></CODE>, <CODE><SPAN CLASS="nowrap">$$arrayref[1]</SPAN></CODE>
   and <CODE><SPAN CLASS="nowrap">$$arrayref[2]</SPAN></CODE>. </DD>
</DL>
You can only call <A HREF="#getoutputparams"><SPAN CLASS="nowrap">getoutputparams()</SPAN></A> when you have retrieved all result sets with
<A HREF="#nextresultset"><SPAN CLASS="nowrap">nextresultset()</SPAN></A> or <A HREF="#get_result_sets"><SPAN CLASS="nowrap">get_result_sets()</SPAN></A>. You can only call <A HREF="#getoutputparams"><SPAN CLASS="nowrap">getoutputparams()</SPAN></A> if the
command batch actually have any output parameters. If you are uncertain, you can
investigate this with <A HREF="#getcmdstate"><SPAN CLASS="nowrap">getcmdstate()</SPAN></A>. Once you have called <A HREF="#getoutputparams"><SPAN CLASS="nowrap">getoutputparams()</SPAN></A> all
resources allocated for the batch are released.
<H2><A NAME="cancelresultset"><SPAN CLASS="nowrap">cancelresultset()</SPAN></A></H2>
<P>Discards all rows in the current result set.</P>
<PRE>$sqlsrv-&gt;cancelresult()</PRE>
<P>When you call <A HREF="#cancelresultset"><SPAN CLASS="nowrap">cancelresultset()</SPAN></A>,
   Win32::SqlServer moves directly to the end of the
   result set without retrieving the rows. You must still call <A HREF="#nextresultset"><SPAN CLASS="nowrap">nextresultset()</SPAN></A>
   to get to the next result set.</P>
<P>If there is no active result set, <A HREF="#cancelresultset"><SPAN CLASS="nowrap">cancelresultset()</SPAN></A> has no effect.</P>
<H2><A NAME="cancelbatch"><SPAN CLASS="nowrap">cancelbatch()</SPAN></A></H2>
<P>Cancels the current command batch and frees all resources allocated for it.</P>
<PRE>$sqlsrv-&gt;cancelbatch()</PRE>
<P>You can call <A HREF="#cancelbatch"><SPAN CLASS="nowrap">cancelbatch()</SPAN></A> at any time. Beware that cancelling a batch does
   not cause <SMALL>SQL</SMALL> Server to roll back any active transaction, unless the setting <SMALL>XACT_ABORT</SMALL> is <SMALL>ON</SMALL>.</P>
<P>Since cancelling a command batch actually means that part of the batch may not be executed at all, using <A HREF="#cancelbatch"><SPAN CLASS="nowrap">cancelbatch()</SPAN></A> casually can lead to
   unexpected results. If you just want to discard all data, it&#39;s better to call
   <A HREF="#get_result_sets"><SPAN CLASS="nowrap">get_result_sets()</SPAN></A> with <CODE>$resultstyle</CODE> = <A HREF="#NORESULT"><SMALL>NORESULT</SMALL></A>, or call
   <A HREF="#cancelresultset"><SPAN CLASS="nowrap">cancelresultset()</SPAN></A> for each result set.</P>
<H2><A NAME="getcmdstate"><SPAN CLASS="nowrap">getcmdstate()</SPAN></A></H2>
<P>Returns the current command state for the Win32::SqlServer object.</P>
<PRE>$cmdstate = $sqlsrv-&gt;getcmdstate()</PRE>
<DL>
   <DT><CODE>$cmdstate</CODE></DT>
   <DD>The current command state. See below for possible values.</DD>
</DL>
<P>You can call <A HREF="#getcmdstate"><SPAN CLASS="nowrap">getcmdstate()</SPAN></A> if you need to examine what to do next, for
   instance if there are any output parameters to retrieve. These are the
   possible return values:</P>
<DL>
   <DT><B><A NAME="CMDSTATE_INIT">CMDSTATE_INIT</A></B></DT>
   <DD>There is no active command batch, and to initiate one, you need to call
   <A HREF="#initbatch"><SPAN CLASS="nowrap">initbatch()</SPAN></A> (or a <A HREF="#High-level">high-level query function</A>).</DD>
   <DT>&nbsp;</DT>
   <DT><B><A NAME="CMDSTATE_ENTEREXEC">CMDSTATE_ENTEREXEC</A></B></DT>
   <DD>A command batch have been entered with <A HREF="#initbatch"><SPAN CLASS="nowrap">initbatch()</SPAN></A>, but it has not yet been
   submitted for execution. You can now define parameters with <A HREF="#enterparameter"><SPAN CLASS="nowrap">enterparameter()</SPAN></A>
   or execute it with <A HREF="#executebatch"><SPAN CLASS="nowrap">executebatch()</SPAN></A>.
   You can also define columns for table parameters with <A HREF="#definetablecolumn"><SPAN CLASS="nowrap">definetablecolumn()</SPAN></A> or
   enter rows to a table parameter with <A HREF="#inserttableparam"><SPAN CLASS="nowrap">inserttableparam()</SPAN></A>.</DD>
   <DT>&nbsp;</DT>
   <DT><B><A NAME="CMDSTATE_NEXTRES">CMDSTATE_NEXTRES</A></B></DT>
   <DD>The command batch has been executed, and you can now retrieve the next
   result set with <A HREF="#nextresultset"><SPAN CLASS="nowrap">nextresultset()</SPAN></A>. You also get this value when you have
   reached the end of the result set with <A HREF="#nextrow"><SPAN CLASS="nowrap">nextrow()</SPAN></A> or
   <SPAN CLASS="nowrap"><A HREF="#cancelresultset">cancelresultset()</A></SPAN>.</DD>
   <DT>&nbsp;</DT>
   <DT><B><A NAME="CMDSTATE_NEXTROW">CMDSTATE_NEXTROW</A></B></DT>
   <DD>There is an active result set, and you should retrieve rows from it with
   <A HREF="#nextrow"><SPAN CLASS="nowrap">nextrow()</SPAN></A> or skip it with <A HREF="#cancelresultset"><SPAN CLASS="nowrap">cancelresultset()</SPAN></A>.</DD>
   <DT>&nbsp;</DT>
   <DT><B><A NAME="CMDSTATE_GETPARAMS">CMDSTATE_GETPARAMS</A></B></DT>
   <DD>You have fetched all result sets, and there are output parameters
   available. You should fetch these with <A HREF="#getoutputparams"><SPAN CLASS="nowrap">getoutputparams()</SPAN></A>.</DD>
</DL>
These constants are not imported by default when you <CODE>use Win32::SqlServer</CODE>. Either refer to them as <CODE>Win32::SqlServer::CMDSTATE_INIT</CODE>
etc or import the constants you need explicitly or with an <A HREF="#EXPORTTAGS">export tag</A>.
<H2><A NAME="midlevelexamples">Mid-Level Functions</A> Examples</H2>
<P>Here are some examples using the mid-level functions. The first example has a
   plain command batch with an output parameter and a result set.</P>
<PRE>use strict;
use Win32::SqlServer qw(CMDSTATE_GETPARAMS);

# Log in to local server with SQL authentication. Stay in tempdb.
my $sqlsrv = new Win32::SqlServer;
$sqlsrv-&gt;setloginproperty(&#39;database&#39;, &#39;tempdb&#39;);
$sqlsrv-&gt;connect();

my $batch = &lt;&lt;&#39;SQLEND&#39;;
   SELECT ? = COUNT(*)
   FROM   Northwind..Orders
   WHERE  CustomerID = ?
     AND  OrderDate  &gt; ?

   SELECT OrderID, OrderDate, Freight
   FROM   Northwind..Orders
   WHERE  CustomerID = ?
     AND  OrderDate &gt; ?
SQLEND
$sqlsrv-&gt;initbatch($batch);

# Enter the parameters. $ok will stay 1 as long as all params are OK,
# This first is an output parameter. To make it easier to retrieve, we
# give it a name.
my $ok = $sqlsrv-&gt;enterparameter(&#39;int&#39;, -1, &#39;@cnt&#39;, 0, 1);

# Then the parameters for the query. Since they both occur twice, we need
# to supply both twice. We don&#39;t care about the names.
$ok &amp;= $sqlsrv-&gt;enterparameter(&#39;nchar&#39;,    5,     undef, 1, 0, &#39;ALFKI&#39;);
$ok &amp;= $sqlsrv-&gt;enterparameter(&#39;datetime&#39;, undef, undef, 1, 0, &#39;1997-06-01&#39;);
$ok &amp;= $sqlsrv-&gt;enterparameter(&#39;nchar&#39;,    5,     undef, 1, 0, &#39;ALFKI&#39;);
$ok &amp;= $sqlsrv-&gt;enterparameter(&#39;datetime&#39;, undef, undef, 1, 0, &#39;1997-06-01&#39;);

if ($ok) {
  $ok = $sqlsrv-&gt;executebatch();
}

if ($ok) {
   while ($sqlsrv-&gt;nextresultset()) {
      my ($rowref);
      while ($sqlsrv-&gt;nextrow($rowref, undef)) {
         print &quot;OrderID: $$rowref{OrderID}   &quot;;
         print &quot;OrderDate: &quot; . substr($$rowref{OrderDate}, 0, 10), &quot;   &quot;;
         print &quot;Freight: $$rowref{Freight}\n&quot;;
      }
   }

   if ($sqlsrv-&gt;getcmdstate() == CMDSTATE_GETPARAMS) {
      my ($paramref);
      $sqlsrv-&gt;getoutputparams($paramref, undef);
      print &quot;The count is: $$paramref{&#39;@cnt&#39;}.\n&quot;;
   }
}
else {
   # Something went wrong somewhere. Issue a cancelbatch to be sure.
   $sqlsrv-&gt;cancelbatch();
}</PRE>
<P>And here is an example that creates a stored procedure with the same contents
   as above. Here we use the <CODE>$arrayref</CODE> for <A HREF="#nextrow"><SPAN CLASS="nowrap">nextrow()</SPAN></A> and
   <A HREF="#getoutputparams"><SPAN CLASS="nowrap">getoutputparams()</SPAN></A> for the sake of the example.</P>
<PRE>use strict;
use Win32::SqlServer qw(:cmdstates);

# Log in to local server with SQL authentication. Stay in tempdb.
my $sqlsrv = new Win32::SqlServer;
$sqlsrv-&gt;setloginproperty(&#39;database&#39;, &#39;tempdb&#39;);
$sqlsrv-&gt;connect();

my $prc = &lt;&lt;&#39;SQLEND&#39;;
CREATE PROCEDURE #orderswithcnt @custid       nchar(5),
                                @orderdate    datetime,
                                @no_of_orders int OUTPUT AS
   SELECT @no_of_orders = COUNT(*)
   FROM   Northwind..Orders
   WHERE  CustomerID = @custid
     AND  OrderDate  &gt; @orderdate

   SELECT OrderID, OrderDate, Freight
   FROM   Northwind..Orders
   WHERE  CustomerID = @custid
     AND  OrderDate &gt; @orderdate
SQLEND

# Create the procedure. We don&#39;t call nextrow here, since there should be
# no rows from this batch.
$sqlsrv-&gt;initbatch($prc);
$sqlsrv-&gt;executebatch();
1 while $sqlsrv-&gt;nextresultset();

# Now let&#39;s try to run the procedure.
$sqlsrv-&gt;initbatch(&#39;{? = call #orderswithcnt(?, ? , ?)}&#39;);

# Enter the parameters. $ok will stay 1 as long as all params are OK,
# Now the first parameter is the return value.
my $ok = $sqlsrv-&gt;enterparameter(&#39;int&#39;, -1, undef, 0, 1);

# Then the parameters for the query.
$ok &amp;= $sqlsrv-&gt;enterparameter(&#39;nchar&#39;, 5, &#39;@custid&#39;, 1, 0, &#39;ALFKI&#39;);
$ok &amp;= $sqlsrv-&gt;enterparameter(&#39;datetime&#39;, undef, &#39;@orderdate&#39;, 1, 0, &#39;1997-06-01&#39;);

# And the output parameter. But T-SQL has no OUTPUT-only parameter,
# so this is input and output.
$ok = $sqlsrv-&gt;enterparameter(&#39;int&#39;, -1, &#39;@no_of_orders&#39;, 1, 1, undef);


if ($ok) {
   $sqlsrv-&gt;executebatch();
}
else {
   # Some parameter failed. Drop out.
   $sqlsrv-&gt;cancelbatch();
   exit;
}

# We can use getcmdstate to see if everything is OK. (Actually, we would
# not be here if there was an error, as the default behaviour is to abort
# in case of error.)
if ($sqlsrv-&gt;getcmdstate() == CMDSTATE_NEXTRES) {
   while ($sqlsrv-&gt;nextresultset()) {
      my ($rowref);
      # In this example we use the arrayref to retrieve the data.
      while ($sqlsrv-&gt;nextrow(undef, $rowref)) {
         print &quot;OrderID: $$rowref[0]   &quot;;
         print &quot;OrderDate: &quot; . substr($$rowref[1], 0, 10), &quot;   &quot;;
         print &quot;Freight: $$rowref[2]\n&quot;;
      }
   }
}

if ($sqlsrv-&gt;getcmdstate() == CMDSTATE_GETPARAMS) {
   my ($paramref);
   $sqlsrv-&gt;getoutputparams(undef, $paramref);
   print &quot;The return value is: $$paramref[0].\n&quot;;
   print &quot;The count is: $$paramref[1].\n&quot;;
}</PRE>
<P>Here is an example with a table valued-parameter, using <A HREF="#definetablecolumn"><SPAN CLASS="nowrap">definetablecolumn()</SPAN></A>
and <A HREF="#inserttableparam"><SPAN CLASS="nowrap">inserttableparam()</SPAN></A>. The type and procedure is the same as in the
<A HREF="#TVP">examples&nbsp; for the high-level routines</A>.</P>
<PRE>use strict;
use Win32::SqlServer;

# Get an object and connect.
my $sqlsrv = new Win32::SqlServer;
$sqlsrv-&gt;setloginproperty(&#39;Database&#39;, &#39;tempdb&#39;);
$sqlsrv-&gt;connect();

# Define the SQL batch. This time we ignore the return value from
# the stored procedure for brevity.
$sqlsrv-&gt;initbatch(&#39;{call myproc(?,?)}&#39;);

# Enter the first parameter.
$sqlsrv-&gt;enterparameter(&#39;char&#39;, 1, &#39;@chr&#39;, 1, 0, &#39;A&#39;);

# Enter the table-valued parameter.
$sqlsrv-&gt;enterparameter(&#39;table&#39;,        # It&#39;s a table-valued parameter.
                        5,              # Number of columns in the table.
                        &#39;@tvp&#39;,         # The name of the parameter.
                        1, 0,           # Is input. Is not output.
                        undef,          # $value. Must be undef here.
                        undef, undef,   # Prec &amp; scale.
                        &#39;mytabletype&#39;); # The table type.

# Now we set up the table. First we define the IDENTITY column. For this
# column we need to specify $usedefault = 1.
$sqlsrv-&gt;definetablecolumn(&#39;@tvp&#39;, &#39;ident&#39;, &#39;int&#39;, 0, undef, undef, 1);

# The remaining columns. Since there is no requirement for an exact
# match, we use initial uppercase for all columns, so that can use the
# column names as keys in a hash without quoting them. For the character
# columns we need to specify the max length. Note that we don&#39;t have to
# specify nullability.
$sqlsrv-&gt;definetablecolumn(&#39;@tvp&#39;, &#39;Chr&#39;,     &#39;char&#39;, 1);
$sqlsrv-&gt;definetablecolumn(&#39;@tvp&#39;, &#39;Intcol&#39;,  &#39;int&#39;);
$sqlsrv-&gt;definetablecolumn(&#39;@tvp&#39;, &#39;Datecol&#39;, &#39;date&#39;);
$sqlsrv-&gt;definetablecolumn(&#39;@tvp&#39;, &#39;String&#39;,  &#39;varchar&#39;, 40);

# We can now insert the rows. First we set up some test data.
my @rows = ({Chr =&gt; &#39;A&#39;, Intcol =&gt; 14, Datecol =&gt; &#39;2009-01-01&#39;,
             String =&gt; &#39;Typewriter&#39;},
            {Chr =&gt; &#39;B&#39;, Intcol =&gt; 9},
            {Chr =&gt; &#39;A&#39;, Intcol =&gt; 5, Datecol =&gt; &#39;1632-11-06&#39;},
            {Chr =&gt; &#39;C&#39;, Intcol =&gt; 12, String =&gt; &#39;Luxury&#39;});

# Then we insert the rows one by one.
foreach my $row (@rows) {
   $sqlsrv-&gt;inserttableparam(&#39;@tvp&#39;, $row);
}

# Execute the procedure.
$sqlsrv-&gt;executebatch();

# We use get_result_sets to get the output, to keep the example shorter.
my %result = $sqlsrv-&gt;get_result_sets(Win32::SqlServer::SINGLEROW,
                                      Win32::SqlServer::HASH);

# Output the result.
print &quot;totalcnt: $result{&#39;totalcnt&#39;}\n&quot;;
print &quot;identsum: $result{&#39;identsum&#39;}\n&quot;;
print &quot;chrcnt:   $result{&#39;chrcnt&#39;}\n&quot;;
print &quot;datecnt:  $result{&#39;datecnt&#39;}\n&quot;;
print &quot;strcnt:   $result{&#39;strcnt&#39;}\n&quot;;</PRE>

<H1><A NAME="OpenSqlFilestream"><SPAN CLASS="nowrap">OpenSqlFilestream()</SPAN></A></H1>
<P>The <NOMEDDLE>OpenSqlFilestream</NOMEDDLE> 
is an <SMALL>API</SMALL> in <SMALL>SQL</SMALL> Server Native Client that permits you
get a file handle to
a <SMALL>FILESTREAM</SMALL> column, so that you can access it with Windows routines such
ReadFile and WriteFile. This provides for faster access to <SMALL>BLOB</SMALL> data, than
going through <SMALL>SQL</SMALL> Server. This is not the least applicable when you use
Win32::SqlServer which is very slow when the <SMALL>BLOB</SMALL> exceeds1MB in size. Win32::SqlServer exposes the 
<NOMEDDLE>OpenSqlFilestream</NOMEDDLE> <SMALL>API</SMALL>, somewhat modified to fit it
into its own mould. To access the file, you would use the module
<NOMEDDLE><CODE>Win32API::File</CODE></NOMEDDLE>.
For a very brief introduction, there is an example at the end of this section.</P>
<P>To use <SPAN CLASS="nowrap"><A HREF="#OpenSqlFilestream">OpenSqlFilestream()</A></SPAN>, the current provider must be <SMALL>SQLNCLI10</SMALL> or later. If you invoke <A HREF="#OpenSqlFilestream"><SPAN CLASS="nowrap">OpenSqlFilestream()</SPAN></A> with the Provider property set to an earlier provider, Win32::SqlServer <CODE>croaks</CODE>. <SPAN CLASS="remark">Those who know SQL Server Native Client may be aware of that <A HREF="#OpenSqlFilestream"><SPAN CLASS="nowrap">OpenSqlFilestream()</SPAN></A> is a static routine, in difference to everything else which is COM-based. However, this has no importance in the context of Win32::SqlServer which loads the API dynamically, to permit Win32::SqlServer to run on systems with older versions with only SQLOLEDB or SQLNCLI.</SPAN></P>
<P>Note: my testing indicates that OpenSqlFilestream() does not work on Windows 10, if you are connected to SQL 2008, be that a local or a remote instance. It works with SQL 2008 R2 and later. The same may apply to Windows Server 2016.</P>
<P>For full details on the
  <SMALL>FILESTREAM</SMALL> feature and the <NOMEDDLE>OpenSqlFilestream</NOMEDDLE> <SMALL>API</SMALL>, please see <A HREF="http://msdn.microsoft.com/en-us/library/bb933972.aspx">Books Online</A>. The
description here is restricted to what you need to know when you use <A HREF="#OpenSqlFilestream"><SPAN CLASS="nowrap">OpenSqlFilestream()</SPAN></A> with Win32::SqlServer.</P>
<PRE>$fh = $sqlsrv-&gt;OpenSqlFilestream($path, $access, $context [, $options [, $alloclen]])</PRE>
<DL>
   <DT><CODE>$fh</CODE></DT>
   <DD>The returned file handle to use with Windows file operations. See below
   what applies in the case <A HREF="#OpenSqlFilestream"><SPAN CLASS="nowrap">OpenSqlFilestream()</SPAN></A> fails.</DD>
   <DT>&nbsp;</DT>
   <DT><CODE>$path</CODE></DT>
   <DD>A path to the <SMALL>FILESTREAM</SMALL> column that you have retrieved from <SMALL>SQL</SMALL> Server
   with the <B>PathName</B> method.</DD>
   <DT>&nbsp;</DT>
   <DT><CODE>$access</CODE></DT>
   <DD>Any of the constants <SMALL>FILESTREAM_READ, FILESTREAM_WRITE</SMALL> or
   <SMALL>FILESTREAM_READWRITE</SMALL>. These constants are not imported by default. Either
   denote them as <CODE><SPAN CLASS="nowrap">Win32::SqlServer::FILESTREAM_READ</SPAN></CODE>, or import them
   explicitly or with an <A HREF="#EXPORTTAGS">export tag</A>. </DD>
   <DT>&nbsp;</DT>
   <DT><CODE>$context</CODE></DT>
   <DD>A binary value that you have retrieved from <SMALL>SQL</SMALL> Server using the
   function <SMALL>GET_FILESTREAM_TRANSACTION_CONTEXT</SMALL>. <CODE>$context</CODE> is interpreted
   according the setting of <B><A HREF="#binary">BinaryAsStr</A></B> in the same way as when you pass binary
   values to other Win32::SqlServer routines. This permits you to retrieve the
   context token from <SMALL>SQL</SMALL> Server and then pass it to
   <A HREF="#OpenSqlFilestream"><SPAN CLASS="nowrap">OpenSqlFilestream()</SPAN></A>, no matter the setting
   of <B><A HREF="#binary">BinaryAsStr</A></B>.</DD>
   <DT>&nbsp;</DT>
   <DT><CODE>$options</CODE></DT>
   <DD>A bit mask of file-access options that controls how the flags are
   opened. See the topic on <NOMEDDLE><A HREF="http://msdn.microsoft.com/en-us/library/bb933972.aspx">OpenSqlFilestream</A></NOMEDDLE> in Books Online for more details.
   You can use the names <SMALL>SQL_FILESTREAM_OPEN_FLAG_ASYNC</SMALL> etc, if you either
   prefix them as Win32::SqlServer::<SMALL>SQL_FILESTREAM_OPEN_FLAG_ASYNC</SMALL> or use an
   <A HREF="#EXPORTTAGS">export tag</A>. Default is 0.</DD>
   <DT>&nbsp;</DT>
   <DT><CODE>$alloclen</CODE></DT>
   <DD>Books Online says &quot;Specifies the initial allocation size of the data
   file in bytes. It is ignored in read mode.&quot; You can specify this parameter
   as an integer value or as a reference to a hash with the keys <B>High</B>
   and <B>Low</B>. If you are using 64-bit Perl, you can always use an integer
   value. With 32-bit Perl and 32-bit integers, you cannot specify a value higher than 2^32-1 if you
   use an integer. By using the hash keys <B>High</B> and <B>Low</B>, you can
   overcome this limitation. <B>Caveat</B>: this parameter does not seem to work as intended when you have 32-bit Perl with 64-bit integers, but I don't have a full understanding of the situation.</DD>
</DL>
<P>If the <NOMEDDLE>OpenSqlFilestream</NOMEDDLE> <SMALL>API</SMALL> returns an error condition, Win32::SqlServer
reports this through the <A HREF="#MsgHandler">current message handler</A>. The
source will be set to
<NOMEDDLE>&quot;OpenSqlFilestream&quot;</NOMEDDLE>
and the error number is the error number set by the
<A HREF="#OpenSqlFilestream"><SPAN CLASS="nowrap">OpenSqlFilestream()</SPAN></A> <SMALL>API</SMALL>, although with a negative number (since positive numbers
are reserved for <SMALL>SQL</SMALL> Server messages). The severity is 16, which means that with
the default error handling in Win32::SqlServer, the script is aborted. If the
settings in <B><A HREF="#ErrInfo">ErrInfo</A></B> are such that execution continues, <A HREF="#OpenSqlFilestream"><SPAN CLASS="nowrap">OpenSqlFilestream()</SPAN></A> returns
the Windows constant <SMALL>INVALID_HANDLE_VALUE</SMALL>, which I assume is a negative number.</P>
<P>Here is a simple example of how to use <A HREF="#OpenSqlFilestream"><SPAN CLASS="nowrap">OpenSqlFilestream()</SPAN></A> together with
Win32<SMALL>API</SMALL>::File to read and write a <SMALL>FILESTREAM</SMALL> column through the file system.
The example assumes that you already have a database with a <SMALL>FILESTREAM</SMALL> file
group.</P>
<PRE>use strict;
use Win32::SqlServer qw(:filestream :rowstyles :resultstyles);

# You need Win32API::File to use ReadFile and WriteFile.
use Win32API::File;

my ($path, $context, $fh, $buffer);

# Connect to server. Change server and database as needed to test
my $sqlsrv = Win32::SqlServer::sql_init(undef, undef, undef, &#39;filestream_test&#39;);

# Create a table with a FILESTREAM column and insert two columns. One with
# data, and one empty that we will write through the file system.
$sqlsrv-&gt;sql(&lt;&lt;&#39;SQLEND&#39;, NORESULT);
CREATE TABLE fstest (guid uniqueidentifier          NOT NULL ROWGUIDCOL UNIQUE,
                     name varchar(23)               NOT NULL PRIMARY KEY,
                     data varbinary(MAX) FILESTREAM NULL)

INSERT fstest (guid, name, data)
   VALUES(newid(), &#39;One&#39;,
          cast(&#39;This string was written from T-SQL.&#39; AS varbinary(MAX))),
         (newid(), &#39;Two&#39;, 0x)
SQLEND

# Let&#39;s read the data we wrote from T-SQL. First retrive the file path and
# transaction context. Note that we must start a transaction.
($path, $context) = $sqlsrv-&gt;sql(&lt;&lt;SQLEND, LIST, SINGLEROW);
BEGIN TRANSACTION
SELECT data.PathName(), get_filestream_transaction_context()
FROM   fstest
WHERE  name = &#39;One&#39;
SQLEND

# Open the filestream.
$fh = $sqlsrv-&gt;OpenSqlFilestream($path, FILESTREAM_READ, $context);

# Read the file. For more info on ReadFile see the manual page for
# Win32API::File and the documentation for the Platform SDK. Note that
# for large files, you may want to read in chunks.
Win32API::File::ReadFile($fh, $buffer, 200000, [], []);
print &quot;We read this from the file: &lt;$buffer&gt;\n&quot;;

# Close this transaction. We must close the file first.
Win32API::File::CloseHandle($fh);
$sqlsrv-&gt;sql(&#39;ROLLBACK TRANSACTION&#39;);

# Now we go writing.
($path, $context) = $sqlsrv-&gt;sql(&lt;&lt;SQLEND, LIST, SINGLEROW);
BEGIN TRANSACTION
SELECT data.PathName(), get_filestream_transaction_context()
FROM   fstest
WHERE  name = &#39;Two&#39;
SQLEND

# Get the file handle.
$fh = $sqlsrv-&gt;OpenSqlFilestream($path, FILESTREAM_WRITE, $context);

# Write to the file. Again, for a large file, you may want to write in
# chunks.
$buffer = &#39;This text was written with WriteFile.&#39;;
Win32API::File::WriteFile($fh, $buffer, 0, [], []);

# Close the transaction.
Win32API::File::CloseHandle($fh);
$sqlsrv-&gt;sql(&#39;COMMIT TRANSACTION&#39;);

# Did it work?
$buffer = $sqlsrv-&gt;sql_one(&lt;&lt;SQLEND, SCALAR);
SELECT convert(varchar(MAX), data)
FROM   fstest
WHERE  name = &#39;Two&#39;
SQLEND

print &quot;We read this from T-SQL: &lt;$buffer&gt;\n&quot;;

# Clean up
$sqlsrv-&gt;sql(&#39;DROP TABLE fstest&#39;);</PRE>
<H1><A NAME="Conversion_Routines">Character-set Conversion Routines</A></H1>
<P>These routines permits you to request that Win32::SqlServer should convert data from one code page to another when sending or receiving data to/from <SMALL>SQL</SMALL> Server. The typical scenario is when you read data from a file in the <SMALL>OEM</SMALL> code page like CP850, and you server uses an <SMALL>ANSI</SMALL> code page like CP1252. Or vice versa: that is you have data in an <SMALL>ANSI</SMALL> file, but your server uses an arcane collation with an <SMALL>OEM</SMALL> code page. <SMALL>OEM</SMALL> data is, hopefully, a rare thing these days.</P>
<P>Caveat: these character-set conversions are performed by Win32::SqlServer
itself, before it passes the data to <SMALL>OLE DB</SMALL>. There may be situations where <SMALL>OLE
DB</SMALL> also performs character-set conversions, particularly if the server&#39;s code
page differs from the client&#39;s code page. Possibly the login property
<B>AutoTranslate</B> controls this.</P>
<H2><A NAME="sql_set_conversion"><SPAN CLASS="nowrap">sql_set_conversion()</SPAN></A> </H2>
<P>Activates a character-set conversion.</P>
<PRE>$sqlsrv-&gt;sql_set_conversion([$client_cs [, $server_cs [, $direction]]]);</PRE>
<DL>
   <DT><CODE>$client_cs</CODE></DT>
   <DD>The character set for your client-side data. Specify the character set as
   a code page, with or without CP. That is, both &quot;850&quot; and &quot;CP850&quot; are good
   values. You can also specify <SMALL>ANSI</SMALL> or <SMALL>OEM</SMALL>
   to specify the <SMALL>ANSI</SMALL> or <SMALL>OEM</SMALL> code pages for the machine. The default value is the
   <SMALL>OEM</SMALL> character set for the client.
   </DD>
   <DT>&nbsp;</DT>
   <DT><CODE>$server_cs</CODE></DT>
   <DD>The character set of the server data. As for <CODE>$client_cs</CODE> you can specify
   the code page with or without CP. The default value is the code page for the
   default collation on the server.</DD>
   <DT>&nbsp;</DT>
   <DT><CODE>$direction</CODE></DT>

   <DD>In which direction conversion is to take place. Three possible values:
   <SMALL>TO_CLIENT_ONLY</SMALL> (convert only data from <SMALL>SQL</SMALL> server) <SMALL>TO_SERVER_ONLY</SMALL> (convert
   only when sending data to <SMALL>SQL</SMALL> Server) and <SMALL>TO_SERVER_CLIENT</SMALL> (convert in both
   directions). These constants are not imported by default. Either denote them
   as <CODE><SPAN CLASS="nowrap">Win32::SqlServer::TO_CLIENT_ONLY</SPAN></CODE>,  import them
   explicitly or use an <A HREF="#EXPORTTAGS">export tag</A>.</DD>
</DL>
<P>If any of the code pages you specify does not exist, <A HREF="#sql_set_conversion"><SPAN CLASS="nowrap">sql_set_conversion()</SPAN></A> <CODE>croaks</CODE>.</P>
<P>If <CODE>$client_cs</CODE> and <CODE>$server_cs</CODE> are the same, the net
   effect that any active conversion is removed.</P>
<P><B>Very important</B>: when you activate a conversion, Win32::SqlServer converts about
   everything that comes its way. Blindly. Command text. Parameter names. Column
   names. Data. Without discrimination. There are at least two cases, when this
   is not likely to be desirable. when you work with the Unicode data types (<B><CODE>nchar</CODE></B>,
   <B><CODE>nvarchar</CODE></B>, <B><CODE>ntext</CODE></B> and <B><CODE>xml</CODE></B>)
   and binary data (<B><CODE>binary</CODE></B>, <B><CODE>varbinary</CODE></B>,
   <B><CODE>image</CODE></B> and <B><CODE>UDT</CODE></B>) when you have <B>
   <A HREF="#binary">BinaryAsStr</A></B> = 0. Thus, you should not
   activate a conversion under these conditions. If you still need to convert
data, you can use <A HREF="#codepage_convert"><SPAN CLASS="nowrap">codepage_convert()</SPAN></A> to convert selectively.</P>
<P>Beware that many character-set conversions are not fully roundtrip. For
instance, if you send the simple statement <CODE>SELECT &#39;Räksmörgås&#39;</CODE>, and
have set up a conversion with CP437 as the client set (the most commonly <SMALL>OEM</SMALL>
set in the <SMALL>US</SMALL>, I believe) and CP1252 (Latin-1) as a the server set, you will get
back <I>RSksmörgss</I>.</P>
<H2><A NAME="sql_unset_conversion"><SPAN CLASS="nowrap">sql_unset_conversion()</SPAN></A> </H2>
<P>Removes any previous conversion.</P>
<PRE>$sqlsrv-&gt;sql_unset_conversion([$direction]);</PRE>
<DL>
   <DT><CODE>$direction</CODE></DT>
   <DD>Specifies in which direction conversion is to be removed. Legal values
   are <SMALL>TO_CLIENT_ONLY</SMALL> (remove only conversion for data going to the client),
   <SMALL>TO_SERVER_ONLY</SMALL> (removes conversion only for data going to the server),
   <SMALL>TO_SERVER_CLIENT</SMALL> (removes all conversions). The default is <SMALL>TO_SERVER_CLIENT</SMALL>.</DD>
</DL>

<H2><A NAME="codepage_convert"><SPAN CLASS="nowrap">codepage_convert()</SPAN></A></H2>
<P>Converts a string from one code page to another.</P>
<PRE>$sqlsrv-&gt;codepage_convert($string, $from_cp, $to_cp);</PRE>
<DL>
   <DT><CODE>$string</CODE></DT>
   <DD>String to convert. Note that <A HREF="#codepage_convert"><SPAN CLASS="nowrap">codepage_convert()</SPAN></A> is not a function, but
   <CODE>$string</CODE> is modified in-place.</DD>
   <DT>&nbsp;</DT>
   <DT><CODE>$from_cp</CODE></DT>
   <DD>The code page that <CODE>$string</CODE> is in. (Or is assumed to be in.) If
   <A HREF="#codepage_convert"><SPAN CLASS="nowrap">codepage_convert()</SPAN></A> finds that <CODE>$string</CODE> has the
   <SPAN CLASS="nowrap"><SMALL>UTF-8</SMALL></SPAN> bit set (this bit is set
   behind the scenes, and not directly settable from a Perl script),
   <A HREF="#codepage_convert"><SPAN CLASS="nowrap">codepage_convert()</SPAN></A> ignores <CODE>$from_cs</CODE>. You cannot use &quot;<SMALL>ANSI</SMALL>&quot; or &quot;<SMALL>OEM</SMALL>&quot; here,
   but you can specify 0 for your <SMALL>ANSI</SMALL> code page, and 1 for your <SMALL>OEM</SMALL> code page.</DD>
   <DT>&nbsp;</DT>
   <DT><CODE>$to_cp</CODE></DT>
   <DD>The code page to convert <CODE>$string</CODE> to. As for <CODE>$from_cp</CODE>, you can specify 0
   and 1 for your <SMALL>ANSI</SMALL> and <SMALL>OEM</SMALL> code pages respectively.</DD>
</DL>
<P>
Internally, <A HREF="#codepage_convert"><SPAN CLASS="nowrap">codepage_convert()</SPAN></A> first converts <CODE>$string</CODE> to Unicode and then to <CODE>$to_cp</CODE>.
Beware that if a character in <CODE>$string</CODE> is not available in <CODE>$to_cp</CODE>, you will get
some replacement character. This can be a similar character, for instance &quot;a&quot; in
place of &quot;å&quot;, or the general fallback character &quot;?&quot;.</P>
<P>
<A HREF="#codepage_convert"><SPAN CLASS="nowrap">codepage_convert()</SPAN></A> is implemented in XS code, which implies some restrictions.
<CODE>$string</CODE> must be a variable; it cannot be a constant string, nor can it be an
expression that normally can be an l-value like <CODE><SPAN CLASS="nowrap">substr($string, 3,
3)</SPAN></CODE> or <CODE>$1</CODE>.</P>
<H1><A NAME="Utility_Routines">Utility Routines</A></H1>
<H2><A NAME="sql_has_errors"><SPAN CLASS="nowrap">sql_has_errors()</SPAN></A></H2>
<P>Returns whether there have been any errors on the Win32::SqlServer object. Presumes that
 <B><A HREF="#SaveMessages">SaveMessages</A></B> is in effect.</P>
<PRE>$haserrors = $sqlsrv-&gt;sql_has_errors([$keepinfomsgs]);</PRE>
<DL>
   <DT><CODE>$haserrors</CODE></DT>

   <DD>True if there are errors in the <B><A HREF="#Messages">Messages</A></B>
   array in <B><A HREF="#ErrInfo">ErrInfo</A></B>, else false.</DD>
   <DT>&nbsp;</DT>
   <DT><CODE>$keepinfomsgs</CODE></DT>

   <DD>Normally, if there are only informational messages and warnings in <B>
   <A HREF="#Messages">Messages</A></B>, <A HREF="#sql_has_errors"><SPAN CLASS="nowrap">sql_has_errors()</SPAN></A> deletes the <B><A HREF="#Messages">Messages</A></B> array from <B>
   <A HREF="#ErrInfo">ErrInfo</A></B> to clear it.
   Pass a true value for this parameter to keep the messages. Note that if there are errors in
   <B><A HREF="#Messages">Messages</A></B>, <A HREF="#sql_has_errors"><SPAN CLASS="nowrap">sql_has_errors()</SPAN></A> retains all messages in <B><A HREF="#Messages">Messages</A></B>, and you
   have to clear it yourself.</DD>
</DL>
<P>The Win32::SqlServer property <B><A HREF="#ErrInfo">ErrInfo</A></B> has an element <B><A HREF="#Messages">Messages</A></B> into which
 <A HREF="#ErrInfo"><SPAN CLASS="nowrap">sql_message_handler()</SPAN></A>, the default message handler
for Win32::SqlServer, saves messages from <SMALL>SQL</SMALL>
 Server if the <B><A HREF="#ErrInfo">ErrInfo</A></B> element <B><A HREF="#SaveMessages">SaveMessages</A></B> is true. In this case
 you can check for errors by calling <A HREF="#sql_has_errors"><SPAN CLASS="nowrap">sql_has_errors()</SPAN></A>. </P>
<P>If <B><A HREF="#SaveMessages">SaveMessages</A></B> is not enabled when you
 call <A HREF="#sql_has_errors"><SPAN CLASS="nowrap">sql_has_errors()</SPAN></A>, and you have Perl warnings enabled,
   Win32::SqlServer issues a
 warning.</P>
<H2><A NAME="sql_get_command_text"><SPAN CLASS="nowrap">sql_get_command_text()</SPAN></A></H2>
<P>Returns the text for the current command batch.</P>
<PRE>$cmdtext = $sqlsrv-&gt;sql_get_command_text();</PRE>
<DL>
   <DT><CODE>$cmdtext</CODE></DT>
   <DD>If the current batch is parameterless, <CODE>$cmdtext</CODE> is simply
   the text of the batch. For a parameterised batch, <CODE>$cmdtext</CODE> is an
   <CODE>EXEC</CODE> of <B>sp_executesql</B> corresponding to the <SMALL>RPC</SMALL> call
   Win32::SqlServer actually performs. For a call to <A HREF="#sql_sp"><SPAN CLASS="nowrap">sql_sp()</SPAN></A>, you get the
   <SMALL>EXEC</SMALL> command your call translates to (although, again, the
   actual call is over <SMALL>RPC</SMALL>). If you use the <A HREF="#Mid-level">mid-level query routines</A>;
   <CODE>$cmdtext</CODE> is simply the text you passed to <A HREF="#initbatch"><SPAN CLASS="nowrap">initbatch()</SPAN></A>.</DD>
</DL>
<P>The one place where this routine can be useful to you, is if you write your
   own <A HREF="#MsgHandler">message handler</A>, and you want to display the lines
   for the current command.</P>
<H2><A NAME="sql_string"><SPAN CLASS="nowrap">sql_string()</SPAN></A></H2>
<P>Quotes a string according to <SMALL>SQL</SMALL> rules.</P>
<PRE>$quotedstring = [$sqlsrv-&gt;]sql_string($string);</PRE>
<DL>
   <DT><CODE>$quoutedstring</CODE></DT>
   <DD>Is <CODE>$string</CODE> bracketed by single quotes(<CODE>&#39;</CODE>), and
   with any single quotes in <CODE>$string</CODE> doubled. For instance <CODE>
   O&#39;Brien</CODE> becomes
   <CODE>&#39;O&#39;&#39;Brien&#39;</CODE>. If <CODE>$string</CODE> is <CODE>undef</CODE>, the return value
   is the string
   <CODE>NULL</CODE>.</DD>
   <DT>&nbsp;</DT>
   <DT><CODE>$sqlsrv</CODE></DT>
   <DD>A Win32::SqlServer object. You don&#39;t have to specify it (it&#39;s not really used
   anyway). <A HREF="#sql_string"><SPAN CLASS="nowrap">sql_string()</SPAN></A> is one of the two items that are imported by default
   when you <CODE>use Win32::SqlServer</CODE>.</DD>
   <DT>&nbsp;</DT>
   <DT><CODE>$string</CODE> </DT>
   <DD>An unquoted string that needs to be quoted to be included in an <SMALL>SQL</SMALL>
   string.</DD>
</DL>
<P>You can use <A HREF="#sql_string"><SPAN CLASS="nowrap">sql_string()</SPAN></A> if you need to embed a string value into a string
   that is to hold an <SMALL>SQL</SMALL> command. However, rather than building complete <SMALL>SQL</SMALL>
   strings, you should <A HREF="#whyparameter">parameterise your commands</A> whenever possible.</P>
<H2><A NAME="sql_begin_trans"><SPAN CLASS="nowrap">sql_begin_trans()</SPAN></A>,
<A NAME="sql_commit"><SPAN CLASS="nowrap">sql_commit()</SPAN></A>, <A NAME="sql_rollback"><SPAN CLASS="nowrap">sql_rollback()</SPAN></A></H2>
<P>Routines to start, commit and rollback transactions.</P>
<PRE>$sqlsrv-&gt;sql_begin_trans()
$sqlsrv-&gt;sql_commit()
$sqlsrv-&gt;sql_rollback()</PRE>
<P>
These routines are just plain wrappers saying <CODE>$sqlsrv-&gt;sql(&quot;BEGIN
TRANSACTION&quot;)</CODE>
etc. Win32::SqlServer does keep any track of its own of transactions.</P>
<P>
They are only included to provide compatibility with <SMALL><A HREF="http://www.sommarskog.se/mssqlperl/mssql-sqllib.html">MSSQL</A></SMALL><A HREF="http://www.sommarskog.se/mssqlperl/mssql-sqllib.html">::Sqllib</A>.</P>

<H1><A NAME="OBJECT_PROPERTIES">Object Properties</A></H1>
<H2><A NAME="AutoConnect">AutoConnect</A></H2>
<P>
<TABLE BORDER=1 CELLSPACING=0 CELLPADDING=0>
<TR><TH>Data type</TH><TD CLASS="extrapad">boolean</TD><TH>Default</TH><TD CLASS="extrapad">false</TD></TR>
</TABLE>
</P>
   <P>If you set <B><A HREF="#AutoConnect">AutoConnect</A></B> to a true value, and you don&#39;t connect explicitly
      with <A HREF="#connect"><SPAN CLASS="nowrap">connect()</SPAN></A> or <A HREF="#sql_init"><SPAN CLASS="nowrap">sql_init()</SPAN></A>,
      Win32::SqlServer will connect when you submit a
      command batch and then disconnect when the command batch has been processed. If
      you use the <A HREF="#High-level">high-level query functions</A> only, connection and disconnection
      happens entirely in these. If you use the <A HREF="#Mid-level">mid-level functions</A>, connection
      happens at <A HREF="#executebatch"><SPAN CLASS="nowrap">executebatch()</SPAN></A>, and disconnection when you have retrieved all
      result sets and the output parameters.</P>
<P>Note that the default behaviour of <SMALL>OLE DB</SMALL> is to pool connections, which means
   that there is a lag time before the actual disconnection occurs. Setting
   <B><A HREF="#AutoConnect">AutoConnect</A></B> on, if you disable connection pooling is likely to be a poor idea.
   See further the login property <B> <A HREF="#Pooling">Pooling</A></B>.</P>
<P>When false, you must connect with <A HREF="#connect"><SPAN CLASS="nowrap">connect()</SPAN></A> or <A HREF="#sql_init"><SPAN CLASS="nowrap">sql_init()</SPAN></A> and remain
   connected to submit queries.</P>
<H2><A NAME="BinaryAsStr">BinaryAsStr</A></H2>
<P>
<TABLE BORDER=1 CELLSPACING=0 CELLPADDING=0>
<TR><TH>Data type</TH><TD CLASS="extrapad">boolean/string</TD><TH>Default</TH><TD CLASS="extrapad">1</TD></TR>
</TABLE>
</P>
<P>Controls how input and output values of the binary data types are
   interpreted. Please see the topic on data-type representation of
   <A HREF="#binary">binary data</A> above for details.</P>
<H2><A NAME="CommandTimeout">CommandTimeout</A></H2>
<P>
<TABLE BORDER=1 CELLSPACING=0 CELLPADDING=0>
<TR><TH>Data type</TH><TD CLASS="extrapad">integer</TD><TH>Default</TH><TD CLASS="extrapad">0</TD></TR>
</TABLE>
</P>
<P>How long Win32::SqlServer should wait before timing out on a command. The default is 0,
   which means wait forever. A time-out error is communicated through the
   <A HREF="#MsgHandler">current message handler</A>. Be aware of that what
   happens is that the <SMALL>OLE DB</SMALL> provider cancels the command, but
it does not
   rollback any outstanding transactions, not even those started in the command
   batch. Thus, if you run into a command timeout, you should issue <CODE>IF
   <SPAN CLASS="nowrap">@@trancount</SPAN> &gt; 0 ROLLBACK TRANSACTION</CODE> to be safe.</P>
<P>If you are <A HREF="#SaveMessages">saving messages</A> and have turned of the 
default to die on errors, and want to test for whether a command timeout has 
occurred, this example demonstrates:</P>
<PRE>my $msgs = $sqlsrv-&gt;{ErrInfo}{Messages};
print &quot;Timeout expired!!!!\n&quot; if $$msgs[$#$msgs]-&gt;{SQLstate} eq &#39;HYT00&#39;;</PRE>
<P>(You should test for the last message, since even if you cleared <B>
<A HREF="#Messages">Messages</A></B> before the call, the batch may have 
generated other messages prior to the timeout.) More about error handling in a 
later section in this manual.</P>
<H2><A NAME="DateFormat">DateFormat</A></H2>
<P>
<TABLE BORDER=1 CELLSPACING=0 CELLPADDING=0>
<TR><TH>Data type</TH><TD CLASS="extrapad">string</TD><TH>Default</TH><TD CLASS="extrapad"><CODE><SPAN CLASS="nowrap">
   &quot;%Y</SPAN><SPAN CLASS="nowrap">%m</SPAN><SPAN CLASS="nowrap">%d</SPAN> <SPAN CLASS="nowrap">%H</SPAN>:<SPAN CLASS="nowrap">%M</SPAN>:<SPAN CLASS="nowrap">%S&quot;</SPAN></CODE></TD></TR>
</TABLE>
</P>
<P>Controls how datetime values are formatted when <B><A HREF="#datetime">DatetimeOption</A></B> has the value
   <A HREF="#DATETIME_STRFMT"><SMALL>DATETIME_STRFMT</SMALL></A>. See further the section on the <A HREF="#datetime">representation of datetime</A>
   values.</P>
<H2><A NAME="DatetimeOption">DatetimeOption</A></H2>
<P>
<TABLE BORDER=1 CELLSPACING=0 CELLPADDING=0>
<TR><TH>Data type</TH><TD CLASS="extrapad">enumerated</TD><TH>Default</TH><TD CLASS="extrapad"><A HREF="#DATETIME_ISO"><SMALL>DATETIME_ISO</SMALL></A></TD></TR>
</TABLE>
</P>
   <P>Controls how datetime value returned from <SMALL>SQL</SMALL> Server are represented in Perl. See
      further the section on the <A HREF="#datetime">representation of datetime</A>
      values.</P>
<H2><A NAME="DecimalAsStr">DecimalAsStr</A></H2>
<P>
<TABLE BORDER=1 CELLSPACING=0 CELLPADDING=0>
<TR><TH>Data type</TH><TD CLASS="extrapad">boolean</TD>
     <TH>Default</TH><TD CLASS="extrapad">false</TD></TR>
</TABLE>
</P>
<P>Whether Win32::SqlServer should return data of the types <B><CODE>bigint</CODE></B>
(in 32-bit Perl),
 <B><CODE>decimal</CODE></B>, <B><CODE>numeric</CODE></B>, <B><CODE>money </CODE>
 </B>and <B><CODE>smallmoney</CODE></B> as strings or floating-point values. See
 further the section on <A HREF="#bignumbers">representation of these data
 types</A>.</P>
<H2>ErrInfo</H2>
<P>
<TABLE BORDER=1 CELLSPACING=0 CELLPADDING=0>
<TR><TH>Data type</TH><TD CLASS="extrapad"><CODE>ref</CODE> to struct</TD><TH>Default</TH><TD CLASS="extrapad"><SMALL>N/A</SMALL></TD></TR>
</TABLE>
</P>
   <P>A complex structure through which you can control how Win32::SqlServer should behave
      when there is an <SMALL>SQL</SMALL> error. This property is detailed in the chapter on
      <A HREF="#ErrInfo">Error
      Handling</A> below.</P>
<H2><A NAME="LogHandle">LogHandle</A></H2>
<P>
<TABLE BORDER=1 CELLSPACING=0 CELLPADDING=0>
<TR><TH>Data type</TH><TD CLASS="extrapad"><CODE>ref</CODE> to file handle</TD><TH>Default</TH><TD CLASS="extrapad"><CODE>undef</CODE></TD></TR>
</TABLE>
</P>
   <P>When you assign the <B><A HREF="#LogHandle">LogHandle</A></B> property a file-handle reference, the
      <A HREF="#High-level">high-level query functions</A> will write the command batches they pass to <SMALL>SQL</SMALL>
      Server to this file.. This does not include queries they submit themselves to find the
      parameters of stored procedures etc. The <A HREF="#Mid-level">mid-level
      functions</A> do not perform any logging.</P>
<P>The logging is implemented with <A HREF="#sql_get_command_text"><SPAN CLASS="nowrap">sql_get_command_text()</SPAN></A>, see this function
   of what you get in the log.</P>
<P>Example:</P>
<PRE>open(F, &#39;MyFile.log&#39;);
$sqlsrv-&gt;{LogHandle} = \*F;
</PRE>
<H2><A NAME="MsecFormat">MsecFormat</A></H2>
<P>
<TABLE BORDER=1 CELLSPACING=0 CELLPADDING=0>
<TR><TH>Data type</TH><TD CLASS="extrapad">string</TD><TH>Default</TH><TD CLASS="extrapad"><CODE><SPAN CLASS="nowrap">
   &quot;%3</SPAN>.3d&quot;</CODE></TD></TR>
</TABLE>
</P>
<P>Controls how the milliseconds portion of a datetime value is formatted
      when <B><A HREF="#datetime">DatetimeOption</A></B> has the value <A HREF="#DATETIME_STRFMT"><SMALL>DATETIME_STRFMT</SMALL></A>. See further the section on the
   <A HREF="#datetime">representation of datetime</A> values.</P>
<H2>MsgHandler</H2>
<P>
<TABLE BORDER=1 CELLSPACING=0 CELLPADDING=0>
<TR><TH>Data type</TH><TD CLASS="extrapad"><CODE>ref</CODE> to <CODE>sub</CODE></TD><TH>Default</TH>
    <TD CLASS="extrapad"><CODE>\&amp;Win32::SqlServer::sql_message_handler</CODE></TD></TR>
</TABLE>
</P>
   <P>The currently installed message handler, which is invoked when <SMALL>SQL</SMALL> Server
      sends a message (error, warning or informational). Also called in case of errors
      from the <SMALL>OLE DB</SMALL> provider and for warnings and errors from
      Win32::SqlServer itself.
      This property is detailed in the chapter on <A HREF="#MsgHandler">Error
      Handling</A>.</P>
<H2><A NAME="NoExec">NoExec</A></H2>
<P>
<TABLE BORDER=1 CELLSPACING=0 CELLPADDING=0>
<TR><TH>Data type</TH><TD CLASS="extrapad">boolean</TD><TH>Default</TH><TD CLASS="extrapad">false</TD></TR>
</TABLE>
</P>
<P>When set, the <A HREF="#High-level">high-level query functions</A> will not
   submit your queries to <SMALL>SQL</SMALL> Server, and they will always return empty
an result
   set. However they will still submit calls to <SMALL>SQL</SMALL> Server to retrieve metadata.</P>
<P>The <A HREF="#Mid-level">mid-level query functions</A> do not honour this
   flag. </P>
<H2><A NAME="procs">procs</A></H2>
<P>
<TABLE BORDER=1 CELLSPACING=0 CELLPADDING=0>
<TR><TH>Data type</TH><TD CLASS="extrapad">ref to hash</TD><TH>Default</TH><TD CLASS="extrapad"><CODE>undef</CODE></TD></TR>
</TABLE>
</P>
   <P>This hash is used by <A HREF="#sql_sp"><SPAN CLASS="nowrap">sql_sp()</SPAN></A> to cache parameter profiles for stored
      procedures. You should never write anything to <B><A HREF="#procs">procs</A></B>. The only permissible
      operation is to delete a key value if you want to force <A HREF="#sql_sp"><SPAN CLASS="nowrap">sql_sp()</SPAN></A> to refresh the cache.</P>
<H2><A NAME="PropsDebug">PropsDebug</A></H2>
<P>
<TABLE BORDER=1 CELLSPACING=0 CELLPADDING=0>
<TR><TH>Data type</TH><TD CLASS="extrapad">boolean</TD><TH>Default</TH><TD CLASS="extrapad">false</TD></TR>
</TABLE>
</P>
   <P>If you get cryptic errors when login fails, because some login property
      has a funny value, it <I>may</I> help to set this property.
      Win32::SqlServer will
      then dump login properties and their status in case of
      an error at login.</P>
<H2><A NAME="Provider">Provider</A></H2>
<P>
<TABLE BORDER=1 CELLSPACING=0 CELLPADDING=0>
<TR><TH>Data type</TH><TD CLASS="extrapad">enumeration</TD><TH>Default</TH><TD CLASS="extrapad">see below</TD></TR>
</TABLE>
</P>
   <P>There are five generations of <SMALL>OLE DB</SMALL> providers that Win32::SqlServer supports for connecting to <SMALL>SQL</SMALL> Server. They are here listed in reverse order of release:</P>
<UL>
   <LI><SMALL>MSOLEDBSQL</SMALL> (<I>Microsoft <SMALL>OLE DB</SMALL> Driver for <SMALL>SQL</SMALL> Server) </I>which is released out-of-band with SQL Server versions. The first version was released in March SQL 2018. Officially, the lowest version it supports is SQL 2012, but it permits connections to SQL 2005 and SQL 2008 as well. This is the recommended version.</LI>
   <LI><SMALL>SQLNCLI11</SMALL> (<I>SQL Server Native Client 11.0</I>) is the version of <SMALL>SQL</SMALL> Server Native Client that ships with <SMALL>SQL</SMALL> 2012 and later versions of SQL Server. </LI>
   <LI><SMALL>SQLNCLI10</SMALL> (<I>SQL Server Native Client 10.0</I>) is the version of <SMALL>SQL</SMALL> Server Native Client that shipped with <SMALL>SQL</SMALL>
   2008.</LI>
   <LI><SMALL>SQLNCLI</SMALL> (<I><SMALL>SQL</SMALL>
   Native Client</I>)
      which shipped with <SMALL>SQL</SMALL>&nbsp;2005.   </LI>
   <LI><SMALL>SQLOLEDB</SMALL> (<I>Microsoft
    <SMALL>OLE DB</SMALL> Provider for <SMALL>SQL</SMALL> Server</I>), which comes
     with all versions of Windows, but only has support on the level of SQL 2000.</LI>
</UL>
<P>There are six different values for this property.</P>
<DL>
   <DT><B><A NAME="PROVIDER_MSOLEDBSQL">PROVIDER_MSOLEDBSQL</A></B></DT>
   <DD>Use <SMALL>Microsoft OLE DB Driver for SQL Server </SMALL>as the <SMALL>OLE DB</SMALL> provider. This is the
     default, if <SMALL>MSOLEDBSQL</SMALL><SMALL></SMALL> is installed.</DD>
   <DT></DT>
   <DT>&nbsp;</DT>
   <DT><B><A NAME="PROVIDER_SQLNCLI11">PROVIDER_SQLNCLI11</A></B></DT>
   <DD>Use <SMALL>SQL</SMALL> Server Native Client 11 as the <SMALL>OLE DB</SMALL> provider. This is the
   default if <SMALL>SQLNCLI11</SMALL> is installed, but <SMALL>MSOLEDBSQL</SMALL> is not available.</DD>
   <DT>&nbsp;</DT>
   <DT><B><A NAME="PROVIDER_SQLNCLI10">PROVIDER_SQLNCLI10</A></B></DT>
   <DD>Use <SMALL>SQL</SMALL> Server Native Client 10 as the <SMALL>OLE DB</SMALL> provider. This is the
   default if <SMALL>SQLNCLI10</SMALL> is installed, but <SMALL>SQLNCLI11</SMALL> and <SMALL>MSOLEDBSQL</SMALL> are not.</DD>
   <DT>&nbsp;</DT>
   <DT><B><A NAME="PROVIDER_SQLNCLI">PROVIDER_SQLNCLI</A></B></DT>
   <DD>Use <SMALL>SQL</SMALL> Native Client as the <SMALL>OLE DB</SMALL> provider. This is the default if
   <SMALL>SQLNCLI</SMALL> is installed, but <SMALL>SQLNCLI10</SMALL> or later is not available.</DD>
   <DT>&nbsp;</DT>
   <DT><B><A NAME="PROVIDER_SQLOLEDB">PROVIDER_SQLOLEDB</A></B></DT>
   <DD>Use the <SMALL>SQLOLEDB</SMALL> provider. This is the default if
   no later version is available. </DD>
   <DT>&nbsp;</DT>
   <DT><B><A NAME="PROVIDER_DEFAULT">PROVIDER_DEFAULT</A></B></DT>
   <DD>Use this value when you want to set the provider to the default provider
   for the machine. When you set the property to this value, Win32::SqlServer will
   automatically change it to one of the other five.</DD>
</DL>
<P>As long as you are connecting to SQL 2005 or later, you can use any of the providers above. (But note that officially, <SMALL>MSOLEDBSQL</SMALL> only supports SQL 2012 and later.) To connect to SQL 2000, the most recent version you can use is SQLNCLI10. For SQL 7, this is SQLNCLI. In practice, you would use SQLOLEDB to connect to these legacy versions.</P>
<P>You cannot set this property when you are connected. You can check whether
   you are connected with the function <A HREF="#isconnected"><SPAN CLASS="nowrap">isconnected()</SPAN></A>.</P>
<H2>QueryNotification</H2>
<TABLE BORDER=1 CELLSPACING=0 CELLPADDING=0 ID="table1">
<TR><TH>Data type</TH><TD CLASS="extrapad">ref to hash</TD><TH>Default</TH><TD CLASS="extrapad">
   <CODE>{}</CODE>, that is, empty</TD></TR>
</TABLE>
<P>You use this property to subscribe to notifications from <SMALL>SQL</SMALL> Server
   when the result set of a query has changed. This hash has three elements: <B>
   Service</B> (string, mandatory), <B>Message</B> (string, optional) and <B>
   Timeout</B> (integer, optional). You set these elements before you run a
   query. When the query has executed, Win32::SqlServer clears this hash. (So that you
   don&#39;t set up query notifications for everything by mistake.)</P>
<P>For more details, please see the section <A HREF="#QueryNotification">Using
   Query Notifications with Win32::SqlServer</A>.</P>
<H2><A NAME="RowsAtATime">RowsAtATime</A></H2>
<P>
<TABLE BORDER=1 CELLSPACING=0 CELLPADDING=0>
<TR><TH>Data type</TH><TD CLASS="extrapad">integer</TD><TH>Default</TH><TD CLASS="extrapad">100</TD></TR>
</TABLE>
</P>
<P>Controls how many rows at a time <A HREF="#nextrow"><SPAN CLASS="nowrap">nextrow()</SPAN></A> requests from the <SMALL>OLE DB</SMALL>
      provider. The idea was that that if the <SMALL>OLE DB</SMALL> provider requests one row
   at a time from <SMALL>SQL</SMALL> Server, this could hurt performance. But I have not
   noticed any difference when I&#39;ve set <B><A HREF="#RowsAtATime">RowsAtATime</A></B> to 1. So I suspect the <SMALL>OLE
   DB</SMALL> providers buffer rows as well.</P>
<H2><A NAME="SQL_version">SQL_version</A></H2>
<P>
<TABLE BORDER=1 CELLSPACING=0 CELLPADDING=0>
<TR><TH>Data type</TH><TD CLASS="extrapad">string</TD><TH>Default</TH><TD CLASS="extrapad"><SMALL>N/A</SMALL></TD></TR>
</TABLE>
</P>
   <P>This is a read-only property that returns the version string, e.g. <CODE>8.00.2039</CODE> for the <SMALL>SQL</SMALL> Server you are connected to. If you try to retrieve the value before you have
   connected the first time, and neither have set <B><A HREF="#AutoConnect">AutoConnect</A></B>, this will fail,
   as Win32::SqlServer in this case tries to connect to get the version number.</P>
<P>Once you have connected, Win32::SqlServer will use a cached value. If you change any of
   the login properties <B><A HREF="#ConnectionString">ConnectionString</A></B>,
   <B><A HREF="#NetworkAddress">NetworkAddress</A></B> or <B>
   <A HREF="#LogPropServer">Server</A></B>, Win32::SqlServer will flush the cached value.</P>
<H2><A NAME="tables">tables</A></H2>
<P>
<TABLE BORDER=1 CELLSPACING=0 CELLPADDING=0>
<TR><TH>Data type</TH><TD CLASS="extrapad"><CODE>ref</CODE> to hash</TD><TH>Default</TH><TD CLASS="extrapad"><CODE>undef</CODE></TD></TR>
</TABLE>
</P>
   <P>This hash is used by <A HREF="#sql_insert"><SPAN CLASS="nowrap">sql_insert()</SPAN></A> to cache column information for tables. You should never write anything to
      <B>tables</B>. The only permissible
      operation is to delete a key if you want to force <A HREF="#sql_insert"><SPAN CLASS="nowrap">sql_insert()</SPAN></A> to refresh the cache.</P>
<H2><A NAME="tabletypes">tabletypes</A></H2>
<P>
<TABLE BORDER=1 CELLSPACING=0 CELLPADDING=0>
<TR><TH>Data type</TH><TD CLASS="extrapad"><CODE>ref</CODE> to hash</TD><TH>Default</TH><TD CLASS="extrapad"><CODE>undef</CODE></TD></TR>
</TABLE>
</P>
   <P>This hash is used by <A HREF="#sql"><SPAN CLASS="nowrap">sql()</SPAN></A>, <A HREF="#sql_one"><SPAN CLASS="nowrap">sql_one()</SPAN></A> and <A HREF="#sql_sp"><SPAN CLASS="nowrap">sql_sp()</SPAN></A> to cache information about table
   types. You should never write anything to
      <B><A HREF="#tabletypes">tabletypes</A></B>. The only permissible
      operation is to delete a key if you want to force Win32::SqlServer to refresh the cache.</P>
<H2>TZOffset</H2>
<P>
<TABLE BORDER=1 CELLSPACING=0 CELLPADDING=0>
<TR><TH>Data type</TH><TD CLASS="extrapad">string</TD><TH>Default</TH><TD CLASS="extrapad"><CODE>undef</CODE></TD></TR>
</TABLE>
</P>
<P>This property sets a default time-zone
for values of the <B><CODE>datetimeoffset</CODE></B> data type. On output, values are shifted into
this time zone, and the time-zone indicator is dropped from the value. On input,
the value of <B><A HREF="#datetime">TZOffset</A></B> is used as the time-zone indicator if none is present in the input
value. The value should be on the form <FONT COLOR="DD0000"><I><CODE>±hh:mm</CODE></I></FONT>,
or &quot;<CODE>local</CODE>&quot; to indicate the local time zone of the client. See
further the section on <A HREF="#datetime">Date and time data types</A>.</P>
<H2><A NAME="UserData">UserData</A></H2>
<P>
<TABLE BORDER=1 CELLSPACING=0 CELLPADDING=0>
<TR><TH>Data type</TH><TD CLASS="extrapad">any</TD><TH>Default</TH><TD CLASS="extrapad"><CODE>undef</CODE></TD></TR>
</TABLE>
</P>
<P>This attribute is not referenced by Win32::SqlServer, but permits you to save your own
   data with a Win32::SqlServer object, would you need it. (You cannot make up a key value
on your own,
   as a Win32::SqlServer object is a tied hash that will reject unknown keys.) If you need to
   store more than one value, you can make <B><A HREF="#UserData">UserData</A></B> a hash, for instance:</P>
<PRE>$sqlsrv-&gt;{UserData}{MyData1} = 4711;</PRE>
<H2><A NAME="usertypes">usertypes</A></H2>
<P>
<TABLE BORDER=1 CELLSPACING=0 CELLPADDING=0>
<TR><TH>Data type</TH><TD CLASS="extrapad"><CODE>ref</CODE> to hash</TD><TH>Default</TH><TD CLASS="extrapad"><CODE>undef</CODE></TD></TR>
</TABLE>
</P>
   <P>This hash is used by <A HREF="#sql"><SPAN CLASS="nowrap">sql()</SPAN></A> and <A HREF="#sql_one"><SPAN CLASS="nowrap">sql_one()</SPAN></A> to cache information about user-defined types.
You should never write anything to
      <B><A HREF="#usertypes">usertypes</A></B>. The only permissible
      operation is to delete a key if you want to force Win32::SqlServer to refresh the cache.</P>

<H1><A NAME="ErrorHandling">Error Handling</A></H1>
<H2>Introduction</H2>
<P>A very simple start: when <SMALL>SQL</SMALL> Server reports
   an error, Win32::SqlServer <CODE>croaks</CODE>, and if you want to catch that, you can use
 <CODE>eval</CODE>. However, this is merely the default behaviour, and there
 are several options to change this.</P>
<P>When you submit a command batch to <SMALL>SQL</SMALL> Server, the batch may produce
 messages. These messages may be errors or purely informational. Since <SMALL>
<SPAN CLASS="nowrap">T-SQL</SPAN></SMALL>
 offers both <SMALL>RAISERROR</SMALL> and <SMALL>PRINT</SMALL> you may think of
   these as different things, but <SMALL>PRINT</SMALL> is really only syntactic sugar for <CODE>
 RAISERROR(&#39;Message&#39;, 0, 1)</CODE>. </P>
<P>The mechanism Win32::SqlServer uses to communicate these messages to your script is a <B>
 callback</B>. You can register a callback that Win32::SqlServer invokes for each message
   from <SMALL>SQL</SMALL> Server by setting the <B>
   <A HREF="#MsgHandler">MsgHandler</A></B> property. You don&#39;t
 have to write your own message handler though, because Win32::SqlServer comes with a default message
 handler, <B><A HREF="#ErrInfo"><SPAN CLASS="nowrap">sql_message_handler()</SPAN></A></B>. This handler is highly configurable
 through the Win32::SqlServer property <B><A HREF="#ErrInfo">ErrInfo</A></B>, and it is also through <B><A HREF="#ErrInfo">ErrInfo</A></B>
 your script can get information about the exact messages. </P>
<P>This chapter describes the <B><A HREF="#ErrInfo">ErrInfo</A></B> property, and thus the behaviour of
 <A HREF="#ErrInfo"><SPAN CLASS="nowrap">sql_message_handler()</SPAN></A>. Then it goes on to discuss the <B><A HREF="#MsgHandler">MsgHandler</A></B>
   property and how to set up your own message handler. At the end of the
   chapter, there are some example scripts that show <B><A HREF="#ErrInfo">ErrInfo</A></B> in play. But first
   two short digressions about possible sources for messages and about error messages and <SMALL>SQL</SMALL>states.</P>
<H2><A NAME="MsgSources">Sources for Messages</A></H2>
<P><SMALL>SQL</SMALL> Server is the mostly likely source to produce an error or an
 informational message, but it is not the only one. This
 section looks at each possible source, and how Win32::SqlServer handles them.</P>
<H3>SQL Server</H3>
<P><SMALL>SQL</SMALL> Server can produce errors or informational
 messages. Informational messages have severity level 0, errors have a severity
   of 11 or higher. (For more details on severity levels, see <B><A HREF="#MaxSeverity">MaxSeverity</A></B>
   below.) Win32::SqlServer passes all messages from <SMALL>SQL</SMALL> Server to the message handler
   defined by <B><A HREF="#MsgHandler">MsgHandler</A></B>.</P>
<H3>The OLE DB Providers</H3>
<P>Win32::SqlServer uses the <SMALL>OLE DB API</SMALL> to call <SMALL>SQL</SMALL> Server; these <SMALL>API</SMALL> calls can result in
   errors. Win32::SqlServer has two different strategies for these errors. 1) <CODE>croak</CODE>. 2) Pass the error to the message
 handler defined by <B><A HREF="#MsgHandler">MsgHandler</A></B>. </P>
<P>Win32::SqlServer has a preference the latter, but the provider does not always give
 enough information for Win32::SqlServer to work from. Consider this sequence:</P>
<PRE>my $sqlsrv = new Win32::SqlServer;
$sqlsrv-&gt;setloginproperty(&#39;IntegratedSecurity&#39;, &#39;Bogus&#39;);
$sqlsrv-&gt;connect();</PRE>
<P>This results in the very cryptic:</P>
<PRE>Internal error: init_ptr-&gt;Initialize failed with 80040e21.
No further error information was collected at F:\Test\example.pl line 7.</PRE>
<P>Provider errors are mainly related to
   the login sequence (for instance, the specified server cannot be found)
   and the use of the <A HREF="#Mid-level">mid-level query routines</A>.
   Win32::SqlServer
   tries to detect conditions that would cause a provider error and forestall
   the provider with its own
   error or warning message, as the provider errors often are obscure.</P>
<P>There are also provider messages that dress up as <SMALL>SQL</SMALL> Server messages, so
   that Win32::SqlServer cannot tell the difference. A typical example is <I>Specified <SMALL>SQL</SMALL>
   server not found.</I> Win32::SqlServer will tell you that this is <SMALL>SQL</SMALL> Server message 6,
   but there is no such message &#8211; and of course, <SMALL>SQL</SMALL> Server did not itself
   report that it wasn&#39;t found.</P>
<H3>Win32::SqlServer</H3>
<P>Win32::SqlServer can detect errors on its own, and as for <SMALL>OLE DB</SMALL> errors,
   Win32::SqlServer can 1)
   <CODE>croak</CODE> or 2) invoke the current message
   handler. Win32::SqlServer can also emit warnings, and these can be reported 1) with
   <CODE>carp</CODE> or 2) through the current message handler.</P>
<P>The basic philosophy is that Win32::SqlServer uses <CODE>croak</CODE>/<CODE>carp</CODE>
   when then error is related to Perl usage while it uses the message handler when the
   condition is related to <SMALL>SQL</SMALL>. So a call <SPAN CLASS="nowrap">
   to
   <A HREF="#executebatch">executebatch()</A></SPAN> without first having called <SPAN CLASS="nowrap"><A HREF="#initbatch">initbatch()</A></SPAN>
   results in an unconditional <CODE>croak</CODE>. Whereas if <A HREF="#sql_sp"><SPAN CLASS="nowrap">sql_sp()</SPAN></A>
   is not able to find the stored procedure you want it to call goes to
   the message handler.&nbsp; </P>
<P>Note: don&#39;t rely too much on what is what, as a certain error could be
   treated differently in a future release. As a hint: it is more likely that
   <CODE>croak</CODE>/<CODE>carp</CODE> is replaced by a call to the message
   handler, than vice versa.</P>
<H3>IDataConvert</H3>
<P>IDataConvert is an <SMALL>OLE DB</SMALL> interface that
   Win32::SqlServer uses to convert data from
   Perl to <SMALL>SQL</SMALL> Server and vice versa. Errors when converting input data are
   communicated through the current message handler, as if they came from
   Win32::SqlServer
   itself; you will never see IDataConvert in an error message.</P>
<P>If an error occurs when converting data from <SMALL>SQL</SMALL> Server back to Perl,
   Win32::SqlServer
   will always <CODE>croak</CODE>. Such an error can only occur if there is a
   bug in Win32::SqlServer or if <SMALL>SQL</SMALL> Server produces garbage.</P>
<H3>Other sources</H3>
<P>Errors and warnings can also come from Perl, Win32 system calls and similar.
   They are never communicated through any message handler, but always through
   <CODE>croak</CODE>/<CODE>carp</CODE>. The one exception are errors that appear
with <A HREF="#OpenSqlFilestream"><SPAN CLASS="nowrap">OpenSqlFilestream()</SPAN></A>. They will be communicated through the current message
handler with <NOMEDDLE>&quot;OpenSqlFilestream&quot; </NOMEDDLE>
as the source for the error message.</P>
<H2><A NAME="errornumbers">Error Numbers and SQLstates</A></H2>
<P>All errors from <SMALL>SQL</SMALL> Server have an error number, from 1 and up. Errors below
 50000 are from <SMALL>SQL</SMALL> Server itself (or a system stored procedure or similar).
 Errors from 50000 and up are from <CODE>RAISERROR</CODE>. <A HREF="#ErrInfo"><SPAN CLASS="nowrap">sql_message_handler()</SPAN></A>
 permits you to control for a specific error number whether Win32::SqlServer should abort
 on it or not.</P>
<P>Win32::SqlServer errors always have number -1. (Currently, I should hasten to add. A
   future version may use more negative numbers.) This is also true for provider errors (save
   for
 those that look like <SMALL>SQL</SMALL> Server messages).</P>
<P>SQLstates are five-letter codes, defined by the <SMALL>ODBC</SMALL>
   standard. They are set by the <SMALL>OLE DB</SMALL> provider for <SMALL>SQL</SMALL>
   Server errors and some of its own errors as well. For <SMALL>SQL</SMALL> Server errors these are of less
   interest, since an SQLstate can cover several error numbers from <SMALL>SQL</SMALL>
   Server. For provider errors, on the other hand, SQLstate is the only way to
   identify the error. (This includes the provider errors that dress up as <SMALL>SQL</SMALL>
   Server errors.) You can find a list
   of all SQLstates in the <SMALL>MSDN</SMALL> topic <A HREF="http://msdn.microsoft.com/en-us/library/windows/desktop/ms714687.aspx"><I>Appendix <SMALL>A: ODBC</SMALL> Error Codes</I></A>.</P>
<P>Not all provider errors have SQLstate. For these errors, Win32::SqlServer passes the
   return code from the <SMALL>OLE DB API</SMALL> function that failed
   as the &quot;SQLstate&quot;,
   formatted as an 8-character hex string. The main purpose of this hex string
   to diagnose problems in Win32::SqlServer itself.</P>
<P>Win32::SqlServer errors never have an SQLstate.</P>
<H2><A NAME="ErrInfo">ErrInfo</A></H2>
<P><B><A HREF="#ErrInfo">ErrInfo</A></B> is a hash and some of the elements are hashes or arrays
   in their turn. Here
   is a pseudo-code declaration of <B><A HREF="#ErrInfo">ErrInfo</A></B>:</P>
<PRE>RECORD ErrInfo
   -- Abort control: On which messages to abort/disconnect.
   MaxSeverity    integer = 10;
   NeverStopOn    HASH OF boolean = undef;
   AlwaysStopOn   HASH OF boolean = undef;
   DisconnectOn   HASH OF boolean =
                  {&#39;2745&#39;  =&gt; 1,  &#39;4003&#39; =&gt; 1,  &#39;5702&#39; =&gt; 1, &#39;17308&#39; =&gt; 1,
                   &#39;17310&#39; =&gt; 1, &#39;17311&#39; =&gt; 1, &#39;17571&#39; =&gt; 1, &#39;18002&#39; =&gt; 1,
                   &#39;08001&#39; =&gt; 1, &#39;08003&#39; =&gt; 1, &#39;08004&#39; =&gt; 1, &#39;08007&#39; =&gt; 1,
                   &#39;08S01&#39; =&gt; 1};

   -- Print control: what parts of a message to print and where.
   PrintMsg       integer = 1;
   PrintText      integer = 0;
   PrintLines     integer = 11;
   CarpLevel      integer = 10;
   NeverPrint     HASH OF boolean = {&#39;5701&#39; =&gt; 1, &#39;5703&#39; =&gt; 1};
   AlwaysPrint    HASH OF boolean = {&#39;3606&#39; =&gt; 1, &#39;3607&#39; =&gt; 1, &#39;3622&#39; =&gt; 1};
   LinesWindow    integer = undef;
   ErrFileHandle  IO::File = STDERR;  -- Where to print errors.

   -- Abort control for return values.
   CheckRetStat   flag = 1;
   RetStatOK      HASH OF boolean = undef;

   -- Return error messages to caller
   SaveMessages   boolean = 0;
   Messages       ARRAY OF RECORD
                     Source    string;
                     Errno     integer;
                     Severity  integer;
                     State     integer;
                     Server    string;
                     Proc      string;
                     Line      string;
                     Text      string;
                     SQLstate  string;
                  END;
END</PRE>
<P>Like Win32::SqlServer itself, <B><A HREF="#ErrInfo">ErrInfo</A></B> is a tied hash that permits only
   the defined
   keys to be used. Thus, if you try to access
   an non-existing element, Win32::SqlServer will <CODE>croak</CODE>. </P>
<H3><A NAME="ErrInfoAbort_control">Abort Control</A></H3>
<P>These elements control whether <A HREF="#ErrInfo"><SPAN CLASS="nowrap">sql_message_handler()</SPAN></A> will abort execution
   or <A HREF="#disconnect"><SPAN CLASS="nowrap">disconnect()</SPAN></A> or because of the message.</P>
<DL>
   <DT><B><A NAME="MaxSeverity">MaxSeverity</A></B></DT>
   <DD>The maximum severity level permitted. That is, if the severity level of
   the message equals <B><A HREF="#MaxSeverity">MaxSeverity</A></B>, <A HREF="#ErrInfo"><SPAN CLASS="nowrap">sql_message_handler()</SPAN></A> will not abort
   execution, but if the severity level is higher, execution will be aborted.
   The default value is 10, which means to stop on any error from <SMALL>SQL</SMALL> Server.
   <P>
   Some guidelines may be in place here, by looking at how the severity levels
   are used:</P>
   <P>
<TABLE BORDER=1 CELLPADDING=0 CELLSPACING=0>
   <TR><TH>Level</TH><TH>Comment</TH></TR>
   <TR><TD>0</TD><TD>Level 0 is informational messages from <SMALL>SQL</SMALL> Server. </TD></TR>
   <TR><TD>1-9</TD><TD>As far as I know, <SMALL>SQL</SMALL> Server itself
   never generates
      messages with these levels, but you can use <SMALL>RAISERROR</SMALL> to
      produce such messages. </TD></TR>
   <TR><TD>10</TD><TD><SMALL>SQL</SMALL> Server cannot produce messages
      with this level. If you specify level 10 with <SMALL>RAISERROR</SMALL>, you do in
      fact get a message with level 0. Win32::SqlServer, on the other hand, can issue
      messages with severity level 10, and they are warnings or provide
      supplementary message ahead of anticipated errors (for instance failed
      conversion of an input value).</TD></TR>
   <TR><TD><SPAN CLASS="nowrap">11-16</SPAN></TD>
     <TD><SMALL>SQL</SMALL> Server uses the levels 11-16 for normal <SMALL>SQL</SMALL> errors &#8211; what Books Online calls
      &quot;user errors&quot; &#8211; in a fairly arbitrary
      fashion. For instance, a <SMALL>NOT NULL</SMALL> violation
   is level 16, while a permission error is level 14. The severity of
   Win32::SqlServer errors and errors from the <SMALL>OLE DB</SMALL> provider
      is always 16.</TD></TR>
   <TR><TD>17-25</TD><TD>Level 17 and above are various resource errors, such as
      running out of disk space, or internal errors in <SMALL>SQL</SMALL> Server. In difference
      to levels 11-16, it really gets more fatal for each level. Then again, if the severity is 20 or higher,
      <SMALL>SQL</SMALL> Server terminates the connection, so for your script the difference
      between 20 and 25 is academic. See more about these levels in <A HREF="http://msdn.microsoft.com/en-us/library/ms164086.aspx">Books
      Online</A>.</TD></TR>
   </TABLE>
</P>
   <P>From this
      follows that the only reasonable values for <B><A HREF="#MaxSeverity">MaxSeverity</A></B> are 10
      (stop on any error), 16 (permit users errors, but stop on resource
      errors), 17-19 (stop on real fatal errors only) and 25 (never stop).</P>
   <P>If you decide to set <B><A HREF="#MaxSeverity">MaxSeverity</A></B> to a higher level than 10, you
      should have a plan to handle errors. If you say &quot;I can&#39;t
      afford to let the script to abort&quot;, then ask yourself if you can afford
   to let the script continue if there was an unhandled error? Maybe you failed
   to write some essential data. Maybe a deadlock prevented you from reading
   important data, causing the script to produce a bogus result if you
   continue.</P>
   <P>
   One strategy is to set <B><A HREF="#SaveMessages">SaveMessages</A></B>, and then use the utility
   function <A HREF="#sql_has_errors"><SPAN CLASS="nowrap">sql_has_errors()</SPAN></A> after each call to a
   Win32::SqlServer function to see if there
   was an error. There are examples of this at the
   <A HREF="#errorhandlingexamples">end of this section</A>.</P></DD>
   <DT><B><A NAME="NeverStopOn">NeverStopOn</A></B></DT>
   <DD>A hash, keyed by <SMALL>SQL</SMALL> Server message numbers or <A HREF="#errornumbers">SQLstates</A> from the <SMALL>OLE DB</SMALL>
   provider. A true value means that for this message, <A HREF="#ErrInfo"><SPAN CLASS="nowrap">sql_message_handler()</SPAN></A> should not abort
   execution.
   <P>
   Say you want to delete a row if there are no references to it. Rather than
   doing an <SMALL>IF EXISTS</SMALL> for each referencing table, you can do this:</P>
<PRE>$sqlsrv-&gt;{ErrInfo}{NeverStopOn}{547}++;
$sqlsrv-&gt;{ErrInfo}{NeverPrint}{547}++;
$sqlsrv-&gt;sql(&#39;DELETE tbl WHERE keycol = ?&#39;, [[&#39;int&#39;, $value]]);
delete $sqlsrv-&gt;{ErrInfo}{NeverStopOn}{547};
delete $sqlsrv-&gt;{ErrInfo}{NeverPrint}{547}++;</PRE>
   <P>
   This both suppresses the error message and prevents execution from being
   aborted. At the same time, if there are other errors that you don&#39;t
   handle, for instance a deadlock or a permission error, they will abort
   execution.</P>
   <P>
   By default, <B><A HREF="#NeverStopOn">NeverStopOn</A></B> is empty.</P></DD>
   <DT><B><A NAME="AlwaysStopOn">AlwaysStopOn</A></B></DT>
   <DD>A hash keyed by <SMALL>SQL</SMALL> Server message numbers or <A HREF="#errornumbers">SQLstates</A> from the <SMALL>OLE DB</SMALL>
   provider. A true value
   means that for this message, <A HREF="#ErrInfo"><SPAN CLASS="nowrap">sql_message_handler()</SPAN></A> should always abort
   execution, even if the message has a severity level &lt;= <B><A HREF="#MaxSeverity">MaxSeverity</A></B>.
   <P>By default, <B><A HREF="#AlwaysStopOn">AlwaysStopOn</A></B> is empty.</P></DD>
   <DT><B><A NAME="DisconnectOn">DisconnectOn</A></B></DT>
   <DD>A hash keyed by <SMALL>SQL</SMALL> Server message numbers or <A HREF="#errornumbers">SQLstates</A> from the <SMALL>OLE DB</SMALL>
   provider. A true value means that for this message, <A HREF="#ErrInfo"><SPAN CLASS="nowrap">sql_message_handler()</SPAN></A> should issue a call to
   <SPAN CLASS="nowrap">
   <A HREF="#disconnect">disconnect()</A> </SPAN>to make sure that the
   connection with <SMALL>SQL</SMALL> Server is terminated..
   <P>As you can see from the pseudo-declaration above,
   by default quite a few message numbers and SQLstates are added to this hash.
   All of these indicate that the physical connection with <SMALL>SQL</SMALL> Server has been
   severed. They appear in <B><A HREF="#DisconnectOn">DisconnectOn</A></B>, as the call to  <A HREF="#disconnect"><SPAN CLASS="nowrap">disconnect()</SPAN></A> is
   needed for Win32::SqlServer to change its internal state to &quot;disconnected&quot;. Thus, you
   should never remove any of the default entries from <B><A HREF="#DisconnectOn">DisconnectOn</A></B>.</P>
   <P>Besides the listed errors,
      <A HREF="#ErrInfo"><SPAN CLASS="nowrap">sql_message_handler()</SPAN></A>, always disconnects if the severity level is &gt;= 20,
      since in this case <SMALL>SQL</SMALL> Server has already severed the connection. This is
      not configurable.</P>
   <P>
   In many cases, it makes sense to reconnect. For instance, if <SMALL>SQL</SMALL> Server was
   restarted, your first query will get a <I>General Network Error</I> message
   from the <SMALL>OLE DB</SMALL> provider with SQLstate 08S01. If you detect this, you can
   reconnect. If you run with <B><A HREF="#AutoConnect">AutoConnect</A></B> on,
   you don&#39;t even have to look for it.</P>
   <P>
   However, keep in mind that if you get disconnected, and you had some sort of transaction
   in progress, it would be wrong to continue with that transaction as if nothing happened,
   since the transaction would have been lost and rolled back.</P>
   <P>
   You can check whether you are connected with the function <A HREF="#isconnected"><SPAN CLASS="nowrap">isconnected()</SPAN></A>.
   (Note that this function reports Win32::SqlServer&#39;s internal connection state.)</P>
   <P>
   Which messages would you add to <B><A HREF="#DisconnectOn">DisconnectOn</A></B>? Well, I can think of one: SQLstate HYT00,
   <I>Timeout expired</I>. Command timeouts are messy, because you don&#39;t really
   know what state the command batch was left in. Particularly, the batch may
   have started a transaction without your knowing. An easy way out could be to
   disconnect and reconnect to give you a known state.<B> Note</B>: by default command timeouts are
   not enabled in Win32::SqlServer, see further the property <B>
   <A HREF="#CommandTimeout">CommandTimeout</A></B>.</P></DD>
   </DL>
<H3><A NAME="errinfo_Print_control">Print Control</A></H3>
<P>A full-blown error message from Win32::SqlServer looks like any of these samples:</P>
<PRE>SQL Server message 15025, Severity 16, State 1, Server KESÄMETSÄ
Procedure sp_addlogin, Line 57
The login &#39;sommar&#39; already exists.
    1&gt; EXEC sp_addlogin @loginame = N&#39;sommar&#39;
Message from SQL Server at F:\Test\example.pl line 8</PRE>
<PRE>Message HYT00 from &#39;Microsoft OLE DB Provider for SQL Server&#39;, Severity: 16
Timeout expired
    1&gt; WAITFOR DELAY &#39;00:00:05&#39;
Message from Microsoft OLE DB Provider for SQL Server at F:\Test\example.pl line 9</PRE>
<PRE>Message -1 from &#39;Win32::SqlServer&#39;, Severity: 16
One or more parameters were not convertible. Cannot execute query.
    1&gt; EXEC sp_executesql N&#39;SELECT @P1&#39;,
    2&gt;      N&#39;@P1 datetime&#39;,
    3&gt;      @P1 = &#39;999&#39;
Message from Win32::SqlServer at F:\Test\example.pl line 8</PRE>
<P>In the context of print-control in <A HREF="#ErrInfo"><SPAN CLASS="nowrap">sql_message_handler()</SPAN></A>, these messages falls
   into four parts, each controlled by an <B><A HREF="#ErrInfo">ErrInfo</A></B> element,
   as detailed below.</P>
<P>By default, errors are written to <SMALL>STDERR, this can be
   overridden with <B><A HREF="#ErrFileHandle">ErrFileHandle</A></B>, see
   below.</SMALL></P>
<DL>
   <DT><B><A NAME="PrintMsg">PrintMsg</A></B></DT>
   <DD>The minimum severity level for which <A HREF="#ErrInfo"><SPAN CLASS="nowrap">sql_message_handler()</SPAN></A> prints the
   &quot;header information&quot; of the message. In the examples, this is the
   first two lines in the first example and the first line in the second
   and third examples. You get
   the message number, the severity level, the state as well as the server, the procedure and
   the line number if
   these are available. Fairly similar to what you see in <SMALL>SQL</SMALL> Server Management Studio.
   <P>
   For messages from the <SMALL>OLE DB</SMALL> provider,
   the message &quot;number&quot; is the <A HREF="#errornumbers">SQLstate</A> for the error. For some errors, <SMALL>OLE DB</SMALL>
   does not produce any SQLstate. In this case, you will in this case see an
   eight-character hex string which is the return code from
   <SMALL>the OLE DB</SMALL> <SMALL>API</SMALL> call that appears as
   &quot;procedure&quot;. In this case, please ignore the return code and the procedure,
   and try to grasp the message text (although it is far from often helpful). Such errors can be the result of user
   errors &#8211; but this is also how internal errors in Win32::SqlServer
   appear if it makes in
   an incorrect <SMALL>API</SMALL> call.</P>
   <P>
   The default is 1, which means that this information are printed for all
   messages except those with severity 0.</P></DD>

   <DT><B><A NAME="PrintText">PrintText</A></B></DT>
   <DD>The minimum severity level for which <A HREF="#ErrInfo"><SPAN CLASS="nowrap">sql_message_handler()</SPAN></A> prints the text
   of the error message. That is, the third line in the first example and the
   second line in the second and third examples. The default is 0, which
   means that it is always printed.</DD>
   <DT>&nbsp;</DT>
   <DT><B><A NAME="PrintLines">PrintLines</A></B></DT>
   <DD>The minimum severity level for which <A HREF="#ErrInfo"><SPAN CLASS="nowrap">sql_message_handler()</SPAN></A> prints the text
   of the command batch that caused the error. The numbers to the left are
   simply line numbers.
   The idea is that if your program stops unexpectedly, you want a clue about
   the <SMALL>SQL</SMALL> code that caused the problem.
   <P>
   Exactly what command text you see here, depends a little on which
   Win32::SqlServer function you called.
   When you call <A HREF="#sql_sp"><SPAN CLASS="nowrap">sql_sp()</SPAN></A>, Win32::SqlServer submits an <SMALL>RPC</SMALL> call to <SMALL>SQL</SMALL> Server. The same is
   true if you submit a parameterised command with <A HREF="#sql"><SPAN CLASS="nowrap">sql()</SPAN></A>. In both these cases,
   Win32::SqlServer produces a textual representation of the corresponding <SMALL>EXEC</SMALL>
   command. When you use parameterised commands with the mid-level
   functions, you will always see the command string you passed to <A HREF="#initbatch"><SPAN CLASS="nowrap">initbatch()</SPAN></A>
   as-is. For some errors detected by Win32::SqlServer, this part is not printed, because
   Win32::SqlServer detects the error before it has constructed the command text, so there
   is nothing to print.</P>
   <P>
   The default is 11. That is, lines are only printed for errors.</P>
   <P>
   See also the element <B><A HREF="#LinesWindow">LinesWindow</A></B> below, with which you can control how much of the
   batch that is printed.</P>
   </DD>
   <DT><B><A NAME="CarpLevel">CarpLevel</A></B></DT>
   <DD>This property controls from which severity level <A HREF="#ErrInfo"><SPAN CLASS="nowrap">sql_message_handler()</SPAN></A>
   supplements the message with a Perl warning (<CODE>carp</CODE>) to indicate
   on which line in your script you submitted the batch that caused the message.
   That is, the last line in the examples.<P>If there is a burst of messages, <A HREF="#ErrInfo"><SPAN CLASS="nowrap">sql_message_handler()</SPAN></A> prints this part
      only once, after the last message. This part never appears on its own.
      Thus, if
      the settings of <B><A HREF="#PrintMsg">PrintMsg</A></B>, <B><A HREF="#PrintText">PrintText</A></B> and <B><A HREF="#PrintLines">PrintLines</A></B> preclude printing the
      message (or all messages in a burst), this part is not printed.</P>
   <P>The default
      is 10. That is, this part is printed for warnings and errors.</P></DD>

   <DT><B><A NAME="NeverPrint">NeverPrint</A></B></DT>
   <DD>A hash, keyed by <SMALL>SQL</SMALL> Server error numbers or SQLstates from the <SMALL>OLE DB</SMALL>
   provider. For entries with true values, printing of all parts of the message
   is suppressed. See above under <B><A HREF="#NeverStopOn">NeverStopOn</A></B>
   for an example on how to use it.
   <P>
   Two <SMALL>SQL</SMALL> Server messages are added by default to <B><A HREF="#NeverPrint">NeverPrint</A></B>.
   Messages 5701 <I>Changed database context to </I>and 5703 is <I>Changed
   language setting to</I> which are always generated on login. Most <SMALL>SQL</SMALL> tools
   suppress these messages.</P></DD>

   <DT><B><A NAME="AlwaysPrint">AlwaysPrint</A></B></DT>
   <DD>A hash, keyed by <SMALL>SQL</SMALL> Server error numbers or SQLstates from the <SMALL>OLE DB</SMALL>
   provider. For entries with true values, <A HREF="#ErrInfo"><SPAN CLASS="nowrap">sql_message_handler()</SPAN></A> prints of all parts of the message.
   <P>Three messages are added to this hash by default. These are the
      informational messages
      for arithmetic errors you get if all of <SMALL>ANSI_WARNINGS,
      ARITHABORT</SMALL> and <SMALL>ARITHIGNORE</SMALL> are off.
      (When you connect with Win3<SMALL>2::SqlServer, ANSI_WARNINGS</SMALL> is on by default.)</P></DD>
   <DT><B><A NAME="LinesWindow">LinesWindow</A></B></DT>
   <DD>If this property is defined, <A HREF="#ErrInfo"><SPAN CLASS="nowrap">sql_message_handler()</SPAN></A> does not print the full
   text of the command batch that caused the error, but only the line on which
   the error occurred according to <SMALL>SQL</SMALL> Server and <B><A HREF="#LinesWindow">LinesWindow</A></B> lines before and after.
   For instance, if you set <B><A HREF="#LinesWindow">LinesWindow</A></B> to 5, you will get at most 11
   lines of code printed in the error message.
   <P>
   By default, <B><A HREF="#LinesWindow">LinesWindow</A></B> is <CODE>undef</CODE>, and thus all lines
   are printed.</P>
  </DD>

   <DT><B><A NAME="ErrFileHandle">ErrFileHandle</A></B></DT>
   <DD>A file handle to which <A HREF="#ErrInfo"><SPAN CLASS="nowrap">sql_message_handler()</SPAN></A> should write the
   messages. If <CODE>undef</CODE> &#8211; which is the default &#8211;
   <A HREF="#ErrInfo"><SPAN CLASS="nowrap">sql_message_handler()</SPAN></A> prints the messages to <SMALL>STDERR</SMALL>.</DD>
</DL>
<H3><A NAME="abortcontrol_sql_sp">Abort Control for <SPAN CLASS="nowrap">sql_sp()</SPAN></A></H3>
<P>The default behaviour for <A HREF="#sql_sp"><SPAN CLASS="nowrap">sql_sp()</SPAN></A> is to abort execution on any non-zero
   return status from a stored procedure. (Return values from scalar
   user-defined functions are not checked.) <B><A HREF="#ErrInfo">ErrInfo</A></B> has two elements to permit you
   control this:</P>
<DL>
   <DT><B><A NAME="CheckRetStat">CheckRetStat</A></B></DT>
   <DD>This element controls whether <A HREF="#sql_sp"><SPAN CLASS="nowrap">sql_sp()</SPAN></A> checks return values at all. By
   default, <B><A HREF="#CheckRetStat">CheckRetStat</A></B> is true. Set it to a false value, if you
   never want
   return values checked.</DD>
   <DT>&nbsp;</DT>
   <DT><B><A NAME="RetStatOK">RetStatOK</A></B></DT>
   <DD>This is a hash, keyed by return values. If an entry has a true value, this
   means that <A HREF="#sql_sp"><SPAN CLASS="nowrap">sql_sp()</SPAN></A> should not abort execution for this return value.</DD>
</DL>
<H3><A NAME="Returning_errors_to_caller">Getting Messages Back</A></H3>
<DL>
   <DT><B><A NAME="SaveMessages">SaveMessages</A></B></DT>
   <DD>When set, all messages that passes through <A HREF="#ErrInfo"><SPAN CLASS="nowrap">sql_message_handler()</SPAN></A> are added
   to the <B><A HREF="#Messages">Messages</A></B> array. <B><A HREF="#SaveMessages">SaveMessages</A></B> is off by default, but you
   should set <B><A HREF="#SaveMessages">SaveMessages</A></B> if you set <B><A HREF="#MaxSeverity">MaxSeverity</A></B> to a value &gt; 10.</DD>
   <DT>&nbsp;</DT>
   <DT><B><A NAME="Messages">Messages</A></B></DT>
   <DD>An array with information about messages generated by <SMALL>SQL</SMALL> Server, the
   <SMALL>OLE DB</SMALL> provider or Win32::SqlServer itself. To check whether there are any errors in <B>
   <A HREF="#Messages">Messages</A></B>, you can use the Win32::SqlServer function
   <A HREF="#sql_has_errors"><SPAN CLASS="nowrap">sql_has_errors()</SPAN></A>. Each entry in
   <B><A HREF="#Messages">Messages</A></B> can contain any of the elements below. Just like <B><A HREF="#ErrInfo">ErrInfo</A></B>, the entries in <B><A HREF="#Messages">Messages</A></B> are tied
   hashes, so if you spell a key wrong, you will get an error. 
   <DL>
     <DT><B>Source</B></DT>
   <DD>The source for the error message. <CODE>undef</CODE> for <SMALL>SQL</SMALL> Server
   messages. The name of the <SMALL>OLE DB</SMALL> provider for <SMALL>OLE DB</SMALL> messages. <I>
   Win32::SqlServer</I> for Win32::SqlServer messages.</DD>
   <DT>&nbsp;</DT>
   <DT><B>Errno</B></DT>
   <DD>The message number. A number &gt; 0 for <SMALL>SQL</SMALL> Server
   messages. -1 for <SMALL>OLE DB</SMALL> and
   Win32::SqlServer messages.</DD>
   <DT>&nbsp;</DT>
   <DT><B>Severity</B></DT>
   <DD>The severity level of the message.</DD>
   <DT>&nbsp;</DT>
   <DT><B>State</B></DT>
   <DD>The state of the message. <SMALL>SQL</SMALL> Server uses state to convey some
   information that is not well documented. Always 1 for <SMALL>OLE DB</SMALL> and
   Win32::SqlServer
   messages. (This has nothing to do with SQLstate.)</DD>
   <DT>&nbsp;</DT>
   <DT><B>Server</B></DT>
   <DD>The server from which the message originated. Always <CODE>undef</CODE> for <SMALL>OLE DB</SMALL> and
   Win32::SqlServer messages. Can also be <CODE>undef</CODE> for <SMALL>SQL</SMALL> Server messages.</DD>
   <DT>&nbsp;</DT>
   <DT><B>Proc</B></DT>
   <DD>The name of the <SMALL>SQL</SMALL> module (stored procedure, trigger etc) where the
   error occurred. Also filled in for some <SMALL>OLE DB</SMALL> messages with internal
   Win32::SqlServer
   debug information.</DD>
   <DT>&nbsp;</DT>
   <DT><B>Line</B></DT>
   <DD>The line in the command batch or in the <SMALL>SQL</SMALL> module,
   that the message
   relates to. It appears that for non-error messages, <SMALL>SQL</SMALL> Server provides bogus
   line numbers. </DD>
   <DT>&nbsp;</DT>
   <DT><B>Text</B></DT>
   <DD>The text of the message.</DD>
   <DT>&nbsp;</DT>
   <DT><B>SQLstate</B></DT>
   <DD>The <A HREF="#errornumbers">SQLstate</A> for the message for <SMALL>SQL</SMALL> Server
   errors and <SMALL>OLE DB</SMALL> messages. Always <CODE>undef</CODE> for
   Win32::SqlServer messages.</DD>
 </DL>
   <P>
   Here is an example on how to refer to an entry in <B><A HREF="#Messages">Messages</A></B>:</P>
   <PRE>$X-&gt;{ErrInfo}{Messages}[0]{Errno}</PRE>
   </DD>
</DL>
<H2><A NAME="MsgHandler">MsgHandler</A></H2>
<H3>Setting a Message Handler</H3>
<P>
The Win32::SqlServer property <B><A HREF="#MsgHandler">MsgHandler</A></B> defines the current message handler. By
default it is set to <CODE><SPAN CLASS="nowrap">\&amp;Win32::SqlServer::sql_message_handler</SPAN></CODE>.
To install your own message handler, you can do any of:</P>
<PRE>$sqlsrv-&gt;{MsgHandler} = \&amp;my_handler;
$sqlsrv-&gt;{MsgHandler} = &quot;main::my_handler&quot;;
$sqlsrv-&gt;{MsgHandler} = &quot;my_handler&quot;;       # Yields a warning.</PRE>
<P>Or even</P>
<PRE>$sqlsrv-&gt;{MsgHandler} = sub { warn &quot;This is my handler!\n&quot;};</PRE>
<P>When you pass the name of a <CODE>sub</CODE>, Win32::SqlServer resolves this name, and
if the <CODE>sub</CODE> does not exist, Win32::SqlServer <CODE>croaks</CODE>. If the
string does not include the name of a package, Win32::SqlServer emits a warning if Perl
warnings are enabled, as the name may resolve to another package than you
intended.</P>
<P>Consider this case:</P>
<PRE>$sqlsrv-&gt;{MsgHandler} = undef;</PRE>
<P>The effect of this is not that you are left without a message handler. When
   there is no Perl callback defined for <B><A HREF="#MsgHandler">MsgHandler</A></B>,
   Win32::SqlServer invokes a second default message handler, implemented in C++. This is a simple, non-configurable
   handler that prints the message header if the severity level is &gt;= 11, and
   always prints the message text. It never prints the <SMALL>SQL</SMALL> code and it never aborts execution.
</P>
<H3>Return Value and Parameters of a Message Handler</H3>
<P>Win32::SqlServer invokes the message handler like this:</P>
<PRE>$status = MsgHandler($sqlsrv, $errno, $state, $severity, $text, $server,
                     $procedure, $line, $sqlstate, $source, $n, $no_of_errs);</PRE>
<DL>
   <DT><CODE>$status</CODE></DT>
   <DD>The return value of the message handler. If this is a false value,
   Win32::SqlServer
   <CODE>croaks</CODE> and aborts execution. You should not call <CODE>die</CODE>, <CODE>croak</CODE>
   or <CODE>exit</CODE> in your message handler, but leave this to
   Win32::SqlServer. This
   is because Win32::SqlServer needs to free resources associated with the current batch.
   (Even if you <CODE>die</CODE>/<CODE>croak</CODE>, someone might catch this
   with <CODE>
   eval</CODE>.)</DD>
   <DT>&nbsp;</DT>
   <DT><CODE>$sqlsrv
</CODE></DT>
   <DD>The Win32::SqlServer object bound to the connection on which the message was
   generated.</DD>
   <DT>&nbsp;</DT>
   <DT><CODE>$errno</CODE></DT>
   <DD>The <A HREF="#errornumbers">error number</A> for the message. For <SMALL>SQL</SMALL>
   Server messages, this is a number &gt; 0. For provider and Win32::SqlServer errors, this is
   always -1. (Except for provider errors that dress up as <SMALL>SQL</SMALL> Server errors.)</DD>
   <DT>&nbsp;</DT>
   <DT><CODE>$state</CODE></DT>
   <DD>The state for the message as reported by <SMALL>SQL</SMALL> Server.</DD>
   <DT>&nbsp;</DT>
   <DT><CODE>$severity</CODE></DT>
   <DD>The severity level of the message. See above under <B><A HREF="#MaxSeverity">MaxSeverity</A></B> for
   a discussion on severity levels.</DD>
   <DT>&nbsp;</DT>
   <DT><CODE>$text</CODE></DT>
   <DD>The message text.</DD>
   <DT>&nbsp;</DT>
   <DT><CODE>$server</CODE></DT>
   <DD>The server from which the message originates. <CODE>undef </CODE>for
   Win32::SqlServer messages and messages from the <SMALL>OLE DB</SMALL> provider.</DD>
   <DT>&nbsp;</DT>
   <DT><CODE>$procedure</CODE></DT>

   <DD>Name of the <SMALL>SQL</SMALL> module (stored procedure, <SMALL>UDF</SMALL>, trigger etc) where the error
   occurred. For messages from the <SMALL>OLE DB</SMALL> provider, it can be the name
   of the <SMALL>API</SMALL> call
   that failed (this  is for debugging Win32::SqlServer itself). Always <CODE>undef</CODE> for
   Win32::SqlServer messages.</DD>
   <DT>&nbsp;</DT>
   <DT><CODE>$line</CODE> </DT>
   <DD>Line number for the line where the error occurred. 0 for Win32::SqlServer messages
   and messages from the <SMALL>OLE DB</SMALL> provider.</DD>
   <DT>&nbsp;</DT>
   <DT><CODE>$sqlstate</CODE></DT>
   <DD>The <A HREF="#errornumbers">SQLstate</A>. See the section above for a
   discussion on SQLstates. Always <CODE>undef</CODE> for Win32::SqlServer messages.</DD>
   <DT>&nbsp;</DT>
   <DT><CODE>$source</CODE></DT>
   <DD>The source for the error message. For <SMALL>SQL</SMALL> Server messages <CODE>$source</CODE>
   is <CODE>undef</CODE>. For <SMALL>OLE DB</SMALL> messages, it is the name of the provider.
   For Win32::SqlServer messages, <CODE>$source</CODE> is <I>Win32::SqlServer</I>.
   For errors from <A HREF="#OpenSqlFilestream"><SPAN CLASS="nowrap">OpenSqlFilestream()</SPAN></A>, source
   is 
   <NOMEDDLE><I>OpenSqlFilestream</I></NOMEDDLE>.</DD>
   <DT>&nbsp;</DT>
   <DT><CODE>$n</CODE></DT>
   <DT><CODE>$no_of_errs</CODE></DT>
   <DD><SMALL>SQL</SMALL> Server may generate more than one message at a time. In this case,
   you may want to display all messages before you abort execution. <CODE>
   $no_of_errs</CODE> is the number of a message in the burst. When you get a
   burst, the message handler is first called with <CODE>$n</CODE> = 1, then 2
   etc up to <CODE>$no_of_errs</CODE>.</DD>
</DL>
<H3>Some Tips on Writing Message Handlers</H3>
<P>If you simply want to change the format of the printed messages, you could
   simply copy the code of <A HREF="#ErrInfo"><SPAN CLASS="nowrap">sql_message_handler()</SPAN></A>, and use <B><A HREF="#ErrInfo">ErrInfo</A></B>
   as before. Beware, though, that <A HREF="#ErrInfo"><SPAN CLASS="nowrap">sql_message_handler()</SPAN></A> makes use of some
   undocumented functions and properties that could disappear in a future
   version.</P>
<P>If you would prefer to replace <B><A HREF="#ErrInfo">ErrInfo</A></B> with your own control
   structure, you can use the <B><A HREF="#UserData">UserData</A></B> property of the
   Win32::SqlServer object.</P>
<P>If you need to get the text of the current command, you can use the function
   <A HREF="#sql_get_command_text"><SPAN CLASS="nowrap">sql_get_command_text()</SPAN></A>. Beware that in some situations this function can
   return <CODE>undef</CODE>, because Win32::SqlServer detects an error before it has
   started to build the command string.</P>
<P>If you are rolling your own entirely, you should consider to have a handling
   similar to what is described under <B><A HREF="#DisconnectOn">DisconnectOn</A></B>. That is, call
   <A HREF="#disconnect"><SPAN CLASS="nowrap">disconnect()</SPAN></A>
   when the <SMALL>SQL</SMALL> Server message or provider message indicates that the connection
   with <SMALL>SQL</SMALL> Server has been terminated.
   Win32::SqlServer does not detect this situation on
   its own, but relies on the message handler to do this work.</P>
<H2><A NAME="errorhandlingexamples">Examples on Error Handling</A></H2>
<H3>Example 1</H3>
<P>This script reads all files named .SP in a directory and passes these to <SMALL>SQL</SMALL>
   Server, assuming they contain stored procedures. The script assumes that the
   procedure name agrees with the file name, and generates a <SMALL>DROP
   PROCEDURE</SMALL> for the procedure prior to running the file. The script
   relies on the built-in printing supplied by <A HREF="#ErrInfo"><SPAN CLASS="nowrap">sql_message_handler()</SPAN></A>. At the end, it
   prints out a summary of many files it attempted to load and how many that
   failed. To this end, it uses <A HREF="#sql_has_errors"><SPAN CLASS="nowrap">sql_has_errors()</SPAN></A>. </P>
<PRE>use strict;
use Win32::SqlServer;

my ($no_of_errors) = 0;
my $dir = shift @ARGV;
my $db  = shift @ARGV;

# Don&#39;t buffer STDOUT, so that we get all output in order.
$| = 1;

# Log in to local server with Windows authentication.
my $sqlsrv = sql_init(undef, undef, undef, $db);

# Since we are loading stored procedures, we don&#39;t want to stop on
# compilation errors.
$sqlsrv-&gt;{ErrInfo}{MaxSeverity} = 17;

# And when there is an error, we only want the line that is flagged
# for the error.
$sqlsrv-&gt;{ErrInfo}{LinesWindow} = 0;

# We need to save messages to see if the file loaded successfully.
$sqlsrv-&gt;{ErrInfo}{SaveMessages} = 1;

# Get the files to load.
chdir($dir) or die &quot;chdir to &#39;$dir&#39; failed: $!\n&quot;;
opendir (D, &#39;.&#39;) or die &quot;Opendir failed: $!\n&quot;;
my @files = grep(/\.sp$/i, readdir(D));
closedir(D);

foreach my $f (@files) {
   # Read the file.
   open (F, $f);
   my @filetext = &lt;F&gt;;
   close F;
   my $filetext = join(&#39;&#39;, @filetext);

   # Log that we try to load the file.
   print &quot;$f\n&quot;;

   # Remove any old copy of the procedure.
   my ($procname) = $f;
   $procname =~ s/\.sp$//i;
   $sqlsrv-&gt;sql(&quot;IF object_id(&#39;$procname&#39;) IS NOT NULL &quot; .
                &quot;DROP PROCEDURE $procname&quot;, Win32::SqlServer::NORESULT);

   # Load the file. We must handle batching with go ourselves.
   my @batches = split(/\n\s*go\s*(\n|$)/i, $filetext);
   foreach my $batch (@batches) {
      next if $batch !~ /\S/;   # Skip blank batches.
      $sqlsrv-&gt;sql($batch, Win32::SqlServer::NORESULT);
   }

   # Check whether it loaded successfully.
   if ($sqlsrv-&gt;sql_has_errors()) {
      $no_of_errors++;
      # We must clear Messages ourselves.
      delete $sqlsrv-&gt;{ErrInfo}{Messages};
   }
}

my $no_of_files = scalar(@files);
print &quot;Attempted to load $no_of_files files whereof &quot; .
      ($no_of_errors ? &quot;$no_of_errors failed&quot; : &quot;all loaded successfully&quot;) .
      &quot;.\n&quot;;</PRE>
<P>Here is a sample output from some files that I had around (and that were not
   in sync with the database I loaded them to):</P>
<PRE>ais_acq_upd_sp.sp
ais_acs_upd_instrument_sp.sp
SQL Server message 207, Severity 16, State 3, Server KESÄMETSÄ
Procedure ais_acs_upd_instrument_sp, Line 166
Invalid column name &#39;sypvarchar&#39;.
  166&gt; SELECT @homecoun = sypvarchar FROM systemparameters WHERE sypcode = &#39;HOMECOUN&#39;
Message from SQL Server at F:\Test\example.pl line 49
ais_acs_upd_money_sp.sp
SQL Server message 207, Severity 16, State 3, Server KESÄMETSÄ
Procedure ais_acs_upd_money_sp, Line 238
Invalid column name &#39;ismainaccountowner&#39;.
  238&gt;         IF NOT(SELECT natregno
Message from SQL Server at F:\Test\example.pl line 49
ais_activate_account_sp.sp
...
ais_sct_exec_one_sp.sp
ais_syp_get_nightjob_ready_ok_sp.sp
Attempted to load 89 files whereof 10 failed.</PRE>
<H3>Example 2</H3>
<P>This example reads a server name, a database name and a file name from the
command line, and loads the specified file into the specified server/database.
The script splits the file into batches and run them one by one. The script
turns off printing of error messages in <A HREF="#ErrInfo"><SPAN CLASS="nowrap">sql_message_handler()</SPAN></A>, and instead prints
the error messages itself. The point is that the line number is modified to
refer to a line in the file, and not in the batch. Thus, if the file first
contains a batch for dropping the procedure if it exists, and there then is an
error on Line 24 in the procedure, the example script will report this error on
Line 28 in the file (if the <SMALL>DROP</SMALL> batch is four lines). This is nice, if you edit
<SMALL>SQL</SMALL> files in an editor like EditPlus from which you can run command-line tools.
You could format the error message, so that you could double-click the error
message and be taken to the line where there error is.</P>
<PRE>use strict;
use Win32::SqlServer;

my $server = shift @ARGV;
my $db     = shift @ARGV;
my $file   = shift @ARGV;

# Don&#39;t buffer STDOUT, so that we get all output in order.
$| = 1;

# Log in to the server with Windows authentication.
my $sqlsrv = sql_init($server, undef, undef, $db);

# Since we are loading stored procedures, we don&#39;t want to stop on
# compilation errors.
$sqlsrv-&gt;{ErrInfo}{MaxSeverity} = 17;

# We will print error messages ourselves, so turn off printing:
$sqlsrv-&gt;{ErrInfo}{PrintMsg}   = 17;
$sqlsrv-&gt;{ErrInfo}{PrintText}  = 17;
$sqlsrv-&gt;{ErrInfo}{PrintLines} = 17;

# We need to save messages so we can print them.
$sqlsrv-&gt;{ErrInfo}{SaveMessages} = 1;

# Read the file.
open (F, $file) or die &quot;Cannot read file &#39;$file&#39;: $!\n&quot;;
my @filetext = &lt;F&gt;;
close F;

print &quot;$file\n&quot;;

# Load the file, batch by batch.
my $batchtext = &#39;&#39;;
my $batchstart = 0;
my $no_of_errs = 0;
foreach my $ix (0..$#filetext) {
   unless ($filetext[$ix] =~ /^\s*go\s*$/i) {
      # Just append.
      $batchtext .= $filetext[$ix];
      next;
   }
   else {
      # Do the batch.
      $no_of_errs += run_batch($sqlsrv, $file, $batchstart, $batchtext);

      # Set up for next;
      $batchstart = $ix + 1;
      $batchtext = &#39;&#39;;
   }
}

# There is likely to be a batch at the end as well...
$no_of_errs += run_batch($sqlsrv, $file, $batchstart, $batchtext);

# Print summary message.
if ($no_of_errs == 0) {
   print &quot;$file loaded successfully!\n&quot;;
}
else {
   print &quot;Loading of $file resulted in $no_of_errs error(s).\n&quot;;
}

exit;

sub run_batch {
    my($sqlsrv, $file, $batchstart, $batchtext) = @_;

    my $no_of_errs = 0;

    # Skip empty batch.
    return 0 if (not $batchtext or $batchtext !~ /\S/);

    # Make sure Messages is empty.
    delete $sqlsrv-&gt;{ErrInfo}{Messages};

    # Run batch.
    $sqlsrv-&gt;sql($batchtext, Win32::SqlServer::NORESULT);

    # Check for messages.
    foreach my $mess (@{$sqlsrv-&gt;{ErrInfo}{Messages}}) {
       # Increase return value.
       $no_of_errs += $mess-&gt;{Severity} &gt;= 11;

       # Translate line number in batch to line number in file.
       my $lineno = $mess-&gt;{Line} + $batchstart;

       # Print message header.
       print &quot;Msg $mess-&gt;{Errno}, Level $mess-&gt;{Severity}, &quot; .
             &quot;Line $lineno, $file\n&quot;;

       # And the message text.
       print $mess-&gt;{Text}, &quot;\n&quot;;
    }

    return $no_of_errs;
}</PRE>
<P>Sample output:</P>
<PRE>F:\Test\OLE DB\blafstest\variant_sp.sp
Msg 170, Level 15, Line 18, F:\Test\variant_sp.sp
Line 15: Incorrect syntax near &#39;4567891234456789&#39;.
Loading of F:\Test\variant_sp.sp resulted in 1 error(s).</PRE>
<P>Notice how the line number in the message text from <SMALL>SQL</SMALL> Server is different from
the line number in the line above.
</P>

<H1><A NAME="Misctopics">Miscellaneous Topics</A></H1>
<H2><A NAME="EXPORTTAGS">Exported Names and Export Tags</A></H2>
<P>To minimize namespace pollution, when you say:</P>
<PRE>use Win32::SqlServer;</PRE>
<P>only two items are imported by default:
   <A HREF="#sql_init"><SPAN CLASS="nowrap">sql_init()</SPAN></A> and <A HREF="#sql_string"><SPAN CLASS="nowrap">sql_string()</SPAN></A>.</P>
<P>A whole lot more can be imported, either explicitly by name, or by an
   export tag. These tags are available:</P>
<DL>
   <DT><CODE>:DEFAULT</CODE></DT>
   <DD>The default import, that is <A HREF="#sql_init"><SPAN CLASS="nowrap">sql_init()</SPAN></A> and <A HREF="#sql_string"><SPAN CLASS="nowrap">sql_string()</SPAN></A></DD>
   <DT>&nbsp;</DT>
   <DT><CODE>:cmdstates</CODE></DT>

   <DD>The possible return values from <A HREF="#getcmdstate"><SPAN CLASS="nowrap">getcmdstate()</SPAN></A>:
   <NOMEDDLE><SMALL>CMDSTATE_INIT, CMDSTATE_ENTEREXEC, CMDSTATE_NEXTRES, CMDSTATE_NEXTROW</SMALL>
   and <SMALL>CMDSTATE_GETPARAMS</SMALL></NOMEDDLE>.</DD>
   <DT>&nbsp;</DT>
   <DT><CODE>:colinfostyles</CODE></DT>
   <DD>The possible values for the <A HREF="#colinfostyles"><CODE>$colinfostyle</CODE></A>
   parameter: <NOMEDDLE><SMALL>COLINFO_NONE, COLINFO_NAMES,
   COLINFO_POS</SMALL> and <SMALL>COLINFO_FULL</SMALL></NOMEDDLE>.</DD>
   <DT>&nbsp;</DT>
   <DT><CODE>:consts</CODE></DT>

   <DD><CODE><A HREF="#SCALAR">$SQLSEP</A></CODE></DD>
   <DT>&nbsp;</DT>
   <DT><CODE>:datetime</CODE></DT>

   <DD>The possible values for the property <B>
   <A HREF="#datetime">DatetimeOption</A></B>: <NOMEDDLE><SMALL>DATETIME_HASH, DATETIME_ISO, DATETIME_REGIONAL, DATETIME_FLOAT</SMALL>
   and <SMALL>DATETIME_STRFMT</SMALL></NOMEDDLE>.</DD>
   <DT>&nbsp;</DT>
   <DT><CODE>:directions</CODE></DT>

   <DD>The possible values for the <CODE>$direction</CODE> parameter to <A HREF="#sql_set_conversion"><SPAN CLASS="nowrap">sql_set_conversion()</SPAN></A>
   and <A HREF="#sql_unset_conversion"><SPAN CLASS="nowrap">sql_unset_conversion()</SPAN></A>:
   <NOMEDDLE><SMALL>TO_SERVER_ONLY, TO_CLIENT_ONLY</SMALL> and
   <SMALL>TO_SERVER_CLIENT</SMALL></NOMEDDLE>.</DD>
   <DT>&nbsp;</DT>
   <DT><CODE>:filestream</CODE></DT>
   <DD>Constants used in conjunction with <A HREF="#OpenSqlFilestream"><SPAN CLASS="nowrap">OpenSqlFilestream()</SPAN></A>: <SMALL>FILESTREAM_READ,
   FILESTREAM_WRITE,
   FILESTREAM_READWRITE, SQL_FILESTREAM_OPEN_FLAG_ASYNC,
   SQL_FILESTREAM_OPEN_FLAG_NO_BUFFERING,
   SQL_FILESTREAM_OPEN_FLAG_NO_WRITE_THROUGH,
   SQL_FILESTREAM_OPEN_FLAG_SEQUENTIAL_SCAN</SMALL> and
   <SMALL>SQL_FILESTREAM_OPEN_FLAG_RANDOM_ACCESS</SMALL></DD>
   <DT>&nbsp;</DT>
   <DT><CODE>:providers</CODE></DT>
   <DD>The possible values for the <B><A HREF="#Provider">Provider</A></B>
   property: <NOMEDDLE><SMALL>PROVIDER_DEFAULT, PROVIDER_SQLOLEDB</SMALL>,
   <SMALL>PROVIDER_SQLNCLI</SMALL>,
   <SMALL>PROVIDER_SQLNCLI10</SMALL> and <SMALL>PROVIDER_SQLNCLI11</SMALL></NOMEDDLE>.</DD>

   <DT>&nbsp;</DT>
   <DT><CODE>:resultstyles</CODE></DT>

   <DD>The possible values for the <CODE><A HREF="#RowResultStyles">$resultstyle</A></CODE> parameter:
   <NOMEDDLE><SMALL>NORESULT, SINGLEROW, SINGLESET, MULTISET,
   MULTISET_RC</SMALL>
   and <SMALL>KEYED</SMALL></NOMEDDLE></DD>
   <DT>&nbsp;</DT>
   <DT><CODE>:returns</CODE></DT>

   <DD>The possible return values from a <A HREF="#Callbacks">callback</A> that
   is used as a <A HREF="#RowResultStyles">result style</A>:
   <NOMEDDLE><SMALL>RETURN_NEXTROW, RETURN_NEXTQUERY, RETURN_CANCEL, RETURN_ERROR</SMALL>
   and <SMALL>RETURN_ABORT</SMALL></NOMEDDLE>.</DD>
   <DT>&nbsp;</DT>
   <DT><CODE>:routines</CODE></DT>

   <DD>All routines that start with sql_. Import these if you want to rely on the
   <A HREF="#sql_init">default handle</A>. Note
   that using the default handle is deprecated. This is the complete import list
   for this tag: <A HREF="#sql"><SPAN CLASS="nowrap">sql()</SPAN></A>, <A HREF="#sql_one"><SPAN CLASS="nowrap">sql_one()</SPAN></A>, <A HREF="#sql_sp"><SPAN CLASS="nowrap">sql_sp()</SPAN></A>, <A HREF="#sql_insert"><SPAN CLASS="nowrap">sql_insert()</SPAN></A>, <A HREF="#sql_has_errors"><SPAN CLASS="nowrap">sql_has_errors()</SPAN></A>, <A HREF="#sql_string"><SPAN CLASS="nowrap">sql_string()</SPAN></A>,
   <SPAN CLASS="nowrap"><A HREF="#sql_get_command_text"><SPAN CLASS="nowrap">sql_get_command_text()</SPAN></A>, <A HREF="#sql_set_conversion">sql_set_conversion()</A></SPAN>,
   <A HREF="#sql_unset_conversion"><SPAN CLASS="nowrap">sql_unset_conversion()</SPAN></A>, <A HREF="#sql_begin_trans"><SPAN CLASS="nowrap">sql_begin_trans()</SPAN></A>, <A HREF="#sql_commit"><SPAN CLASS="nowrap">sql_commit()</SPAN></A> and <A HREF="#sql_rollback"><SPAN CLASS="nowrap">sql_rollback()</SPAN></A>.</DD>
   <DT>&nbsp;</DT>
   <DT><CODE>:rowstyles </CODE></DT>
   <DD>The possible values for the <CODE><A HREF="#RowResultStyles">$rowstyle</A></CODE>
   parameter: <NOMEDDLE><SMALL>SCALAR, LIST</SMALL>
   and <SMALL>HASH</SMALL></NOMEDDLE>.</DD>
</DL>
<P>Here is an example,
on how to import <A HREF="#sql_init"><SPAN CLASS="nowrap">sql_init()</SPAN></A>, the result styles, the row styles and the property
value <A HREF="#DATETIME_REGIONAL"><SMALL>DATETIME_REGIONAL</SMALL></A>:
</P>
<PRE>use Win32::SqlServer qw(:rowstyles :resultstyles sql_init DATETIME_REGIONAL);</PRE>
<P>All export tags must come before any explicit names. For more information about importing names and using export tags, please
   refer to the Perl documentation.</P>
<H2><A NAME="Versionnumbers">Getting the Win32::SqlServer Version</A>&nbsp;&nbsp; </H2>
<P>If you need to check which version of Win32:SqlServer that is installed,
there are two variables available: <CODE><SPAN CLASS="nowrap">$Win32::SqlServer::VERSION</SPAN></CODE>
and <SPAN CLASS="nowrap"><CODE>$Win32::SqlServer::Version</CODE></SPAN>. The former is just the
version string, for instance 2.009. The latter also includes a copyright blurb.
There are no export tags for these two.</P>
<H2><A NAME="QueryNotification">Using Query Notification with Win32::SqlServer</A></H2>
<P>Query notification is a feature added in <SMALL>SQL</SMALL>&nbsp;2005
 that uses the  Service Broker infrastructure. It is a little funny in that
 you cannot set up a subscription query notification from plain
 <SMALL><SPAN CLASS="nowrap">T-SQL</SPAN></SMALL>, you must do it from client code. In
 <SMALL>ADO</SMALL> .Net this is packaged in the SqlDependency
 class for a little more elegance, but the feature is available in
 <SMALL>SQL</SMALL> Server Native Client as well, and
 Win32::SqlServer gives you access to query
 notification through the <B><A HREF="#QueryNotification">QueryNotification</A></B>
 hash. </P>
<P>For full information on Query Notification, please see topic <A HREF="http://msdn.microsoft.com/en-us/library/ms175110.aspx"><I>Using Query Notifications</I></A> in Books Online. Here follows a crash
  course in the context of Win32::SqlServer. The <B><A HREF="#QueryNotification">QueryNotification</A></B> hash has three
elements:</P>
<DL>
  <DT><B>Service</B></DT>
   <DD>A property-value string that specifies the service options for the
   notification. The string has this format:
   <PRE>service=<I>service-name</I>[;(local database=<I>db</I>|broker instance=<I>instance</I>)]</PRE>
   This element is mandatory. If you do not set this element, Win32::SqlServer will
   not set up a notification. If other elements in the hash are set, but <B>Service</B>
   is not, Win32::SqlServer emits a warning through the current message handler, if Perl
   warnings are enabled.</DD>
   <DT>&nbsp;</DT>
   <DT><B>Message</B></DT>
   <DD>This is a text in free format that reappears in the message body of the
   notification message, so that you can identify which notification fired, if you have
   submitted more than one. If you don&#39;t set this element, Win32::SqlServer will set a
   default message of <I>Query notification set by Win32::SqlServer</I>. The same applies
   of you set <B>Message</B> to the empty string.</DD>
   <DT>&nbsp;</DT>
   <DT><B>Timeout</B></DT>
   <DD>An integer value that specifies how many seconds you want the
   notification subscription to be active. It seems that Service Broker only
   clears out subscriptions about every minute or so, so if you set a small
   value, you may find that the subscription lives longer than you expected. If
   you do not specify any timeout, it appears that you get a timeout of 432000
   seconds, or five days.</DD>
</DL>
<P>So how do you use this? You set the <B><A HREF="#QueryNotification">QueryNotification</A></B> property before you
   submit a query batch, and the notification subscriptions then apply to the
   queries in that batch. Once Win32::SqlServer has submitted the batch, it clears out the
   <B><A HREF="#QueryNotification">QueryNotification</A></B> hash, so you will have to set it again to set up more
   notification subscriptions. Note that you cannot set up query notification for
   any query, but queries must adhere to certain rules, similar to those that
   apply for indexed views. Please refer to Books Online for details.</P>
<P>Here is an example of how to use query notification with Win32::SqlServer. First run
   this in a query window:</P>
<PRE>CREATE QUEUE MyQueue WITH RETENTION = OFF
CREATE SERVICE OlleService ON QUEUE MyQueue
([http://schemas.microsoft.com/SQL/Notifications/PostQueryNotification])
go
CREATE TABLE QNtest (a int NOT NULL PRIMARY KEY,
                     b nchar(5) NOT NULL,
                     c datetime NOT NULL)
go
INSERT QNtest (a, b, c)
SELECT 1, &#39;ALFKI&#39;, &#39;19991212&#39;</PRE>
<P>This snippet sets up a query notification on QNtest, and then polls to see if
   there are any notifications:</P>
<PRE>$sqlsrv-&gt;{QueryNotification}{Service} =
         &#39;service=MyService;local database=somedatabase&#39;;
$sqlsrv-&gt;sql(&quot;SELECT a, b, c FROM dbo.QNtest WHERE b = N&#39;ALFKI&#39;&quot;);
my @notification;
while (not @notification) {
   @notification = $sqlsrv-&gt;sql(&lt;&lt;&#39;SQLEND&#39;);
      DECLARE @xml TABLE (x xml NOT NULL);
      RECEIVE convert(xml, message_body) FROM MyQueue INTO @xml;
      WITH XMLNAMESPACES
         (&#39;http://schemas.microsoft.com/SQL/Notifications/QueryNotification&#39; AS qn)
      SELECT Message = c.value(N&#39;(qn:Message)[1]&#39;, &#39;nvarchar(MAX)&#39;),
             Source  = c.value(N&#39;@source&#39;, &#39;nvarchar(255)&#39;),
             Info    = c.value(N&#39;@info&#39;, &#39;nvarchar(255)&#39;),
             Type    = c.value(N&#39;@type&#39;, &#39;nvarchar(255)&#39;)
      FROM @xml x
      CROSS APPLY x.x.nodes(N&#39;/qn:QueryNotification&#39;) AS T(c)
SQLEND
   sleep(1) unles @notification;
} </PRE>
<P>There is a lot of new <SMALL>SQL</SMALL>&nbsp;2005 features in
   this sample: The <SMALL>RECEIVE</SMALL> command, part of the
   Service Broker infrastructure, is how you receive your notifications. In this
   sample I take the message body (or bodies) which for query notifications are
   <SMALL>XML</SMALL> document and save them into a table. Then
   I use XQuery to extract the information from the <SMALL>XML</SMALL>
   into pieces that the Perl code then can work with. </P>
<P>There are several ways to achieve a notification: insert a row with b =
   <SMALL>ALFKI</SMALL>, delete the row there already is &#8211;
   or just drop the table. Thus, when you have received a notification, you
   need to inspect <CODE><SPAN CLASS="nowrap">@notification</SPAN></CODE> to see what event(s) occurred.
   Note that if <SMALL>SQL</SMALL> Server cannot set up a
   subscription, for instance, because the query breaks the rules, you will not
   get an error when you run the query. Instead you will get an immediate
   notification with <CODE><SPAN CLASS="nowrap">$$notification[0]{Source}</SPAN></CODE> set to
   &#39;statement&#39;. Once you
   have received a notification from your subscription, the subscription is no
   longer active, but you would have to resubmit the query with the
   <B><A HREF="#QueryNotification">QueryNotification</A></B> hash set to get
   further notifications.</P>
<P>Again, please refer to Books Online for more details on query notification.
   For instance, I have been entirely silent on permissions here.</P>
<H2><A NAME="Threads">Using Win32::SqlServer in Threaded Scripts</A></H2>
<P>Win32::SqlServer is designed to be thread-safe and should work with Perl threads
 as in <CODE>use threads</CODE>, as well as running parallel Active-X scripts from
   tools like <SMALL>DTS</SMALL> or <SMALL>ISAPI.</SMALL></P>
<P>When you create a new thread, Win32::SqlServer objects visible to the parent thread are
 copied to child thread as well. These child objects inherit some data but not all
 from the parent object:</P>
<UL>
   <LI>The settings of all <A HREF="#OBJECT_PROPERTIES">Win32::SqlServer properties</A>
      with the exception of <B><A HREF="#Provider">Provider</A></B>, are
      inherited.</LI>
   <LI>No <A HREF="#setloginproperty">login properties</A> are inherited.</LI>
   <LI>No matter if the parent was connected or not, the child object is not
      connected.</LI>
</UL>
<P>Thus, a new-born child process will have to fill in login information and
 connect to the database (unless you have set <B><A HREF="#AutoConnect">AutoConnect</A></B>).
 The child and parent objects are distinct objects, and changes to one will not
 affect the other.</P>
<P><CODE>share </CODE>from the package <CODE>threads::shared</CODE>, does not
 work with Win32::SqlServer objects. </P>
<H2><A NAME="BUGS">Bugs and Known Restrictions</A></H2>
<H3>Issue 1</H3>
<P>When all this is true:</P>
<UL>
   <LI>You run a stored procedure.</LI>
   <LI><SMALL>NOCOUNT</SMALL> is ON.</LI>
   <LI>An error is raised. </LI>
   <LI>A result set is returned after the error. </LI>
   <LI>You are using the <SMALL>SQL</SMALL>&nbsp;2000 or earlier
   or you are using <SMALL>SQLOLEDB</SMALL> as your <SMALL>OLE DB</SMALL> provider.</LI>
</UL>
<P>then Win32::SqlServer fails to return the result set that comes directly after the
 error. (Subsequent result sets are returned.) Consider this procedure:</P>
<PRE>CREATE PROCEDURE errors_with_result @nocount bit AS
   IF @nocount = 1
      SET NOCOUNT ON
   ELSE
      SET NOCOUNT OFF
   RAISERROR(&#39;Hi there!&#39;, 16, 1)
   SELECT getdate()
   SELECT @@version</PRE>
<P>When you run this procedure and pass 1 for the <CODE><SPAN CLASS="nowrap">@nocount</SPAN></CODE>
   parameter, you will not get the result set for <CODE><SPAN CLASS="nowrap">getdate()</SPAN></CODE>, but you
   will get the result set for <CODE><SPAN CLASS="nowrap">@@version</SPAN></CODE>.</P>
<P>This is due to some combination of bugs in <SMALL>SQL</SMALL> Server and the <SMALL>OLE
 DB</SMALL> providers, which have been fixed with the release of <SMALL>SQL</SMALL>&nbsp;2005. But
   if you connect to <SMALL>SQL</SMALL>&nbsp;2000 or earlier, or use the <SMALL>SQLOLEDB</SMALL> provider, you are
   exposed to this bug.</P>
<H3>Issue 2 </H3>
<P>Messages issued with <SMALL>RAISERROR WITH NOWAIT</SMALL> are delayed, and appears one slot
 too late. Consider this batch:</P>
<PRE>RAISERROR(&#39;One&#39;, 0, 1) WITH NOWAIT
WAITFOR DELAY &#39;00:00:05&#39;
RAISERROR(&#39;Two&#39;, 0, 1) WITH NOWAIT
WAITFOR DELAY &#39;00:00:05&#39;
RAISERROR(&#39;Three&#39;, 0, 1) WITH NOWAIT
WAITFOR DELAY &#39;00:00:05&#39;</PRE>
<P>It should print <I>One</I> immediately,
 after five seconds print <I>Two</I>, after ten seconds print <I>Three</I> and then
 five seconds later terminate. However, when Win32::SqlServer runs this batch, it does not
   print <I>One</I> until five seconds have elapsed, <I>Two</I> appears after
   ten seconds and <I>
   Three</I> not until 15 seconds as the script terminates.</P>
<P>This is a behaviour you can reproduce with several other APIs built on top of
 <SMALL>OLE DB</SMALL>, for instance <SMALL>ADO</SMALL> or the OleDb .Net Data
   provider. Nevertheless, if you
 run the batch above in <SMALL>SQLCMD</SMALL> for <SMALL>SQL</SMALL> 2005 and <SMALL>SQL</SMALL> 2008, which uses <SMALL>OLE DB</SMALL>, you get the correct result. Thus,
 Win32::SqlServer should be able do this correctly, but for now it doesn&#39;t.</P>
<H3>Issue 3</H3>
<P>Performance is poor when retrieving large objects. Retrieving a single 5MB <B><CODE>
 varchar(MAX)</CODE></B> value could take 5-10 depending on your hardware. <SMALL>A 50
   MB</SMALL> value could take ten times as long. A similar issue exists with passing large amount of data to table-valued parameters.</P>
<P>The root cause is that Win32::SqlServer does not have any particular support for large
 types, and does not use streaming to retrieve them. I hope to add this in a
 later release.</P>
<H3>Issue 4</H3>
<P>You cannot use the <CODE>share</CODE> operator from the <CODE>threads::shared</CODE>
   package. I don&#39;t know if this is a problem in my code, or a restriction with
   <CODE>threads::shared</CODE>. Thus, you cannot share Win32::SqlServer objects between
   threads.</P>

<H1><A NAME="ACKNOWLEDGEMENTS">Acknowledgements</A></H1>
<P>Once upon a time Larry Wall invented Perl. Somewhat later Michael Peppler
 wrote Sybperl for Unix. Christian Mallwitz ported Sybperl to Windows NT. Thanks
 to their work I was able to convert Sybase::DBlib into <SMALL>MSSQL</SMALL>::DBlib, and
 without that base to stand on, I would not have been able to develop the XS
 parts of Win32::SqlServer. The Sybperl distribution contained a simple <CODE>
   <SPAN CLASS="nowrap">sql()</SPAN></CODE> routine contributed by Gisle Aas. Simple as it may have been, it
 was from this routine that <SMALL>MSSQL</SMALL>::Sqllib was woven, and that interface made it
 to Win32::SqlServer as well.</P>
<P>I also need to thank the people in the perl.xs and perl.unicode newsgroups for
 answering my questions, and particularly Jarkko Hietaniemi and Nick Ing-Simmons. </P>
<H1><A NAME="AUTHOR">Author</A>, Copyright and Licence</H1>
<P>&copy; 2005-2012 Erland Sommarskog &lt;<A HREF="mailto:esquel@sommarskog.se">esquel@sommarskog.se</A>&gt;.</P>
<P>This module is available under any license you
 want, as long as you don&#39;t claim that you wrote it yourself.</P>
<HR />
<I>
This file was last updated <!--$$Modtime:--> 18-04-17 21:32 <!-- $-->
</I>
</BODY>
</HTML>