This is the multi-page printable view of this section.
Click here to print.
Return to the regular view of this page.
Programming ADO.NET applications
The Vertica driver for ADO.NET allows applications written in C# to read data from, update, and load data into Vertica databases.
The Vertica driver for ADO.NET allows applications written in C# to read data from, update, and load data into Vertica databases. It provides a data adapter (Vertica Data Adapter) that facilitates reading data from a database into a data set, and then writing changed data from the data set back to the database. It also provides a data reader (VerticaDataReader) for reading data. The driver requires the .NET framework version 3.5+.
For more information about ADO.NET, see:
Note
All of the examples provided in this section are in C#.
1 - ADO.NET data types
This table details the mapping between Vertica data types and .NET and ADO.NET data types.
This table details the mapping between Vertica data types and .NET and ADO.NET data types.
.NET Framework Type |
ADO.NET DbType |
VerticaType |
Vertica Data Type |
VerticaDataReader getter |
Boolean |
Boolean |
Bit |
Boolean |
GetBoolean() |
byte[] |
Binary |
Binary
VarBinary
LongVarBinary
|
Binary
VarBinary
LongVarBinary
|
GetBytes()
Note
The limit for LongVarBinary is 32 Million bytes. If you attempt to insert more than the limit during a batch transfer for any one row, then they entire batch fails. Verify the size of the data before attempting to insert a LongVarBinary during a batch.
|
Datetime |
DateTime |
Date
Time
TimeStamp
|
Date
Time
TimeStamp
|
GetDateTime()
Note
The Time portion of the DateTime object for vertica dates is set to DateTime.MinValue. Previously, VerticaType.DateTime was used for all date/time types. VerticaType.DateTime still exists for backwards compatibility, but now there are more specific VerticaTypes for each type.
|
DateTimeOffset |
DateTimeOffset |
TimestampTZ
TimeTZ
|
TimestampTZ
TimeTZ
|
GetDateTimeOffset()
Note
The Date portion of the DateTime is set to DateTime.MinValue
|
Decimal |
Decimal |
Numeric |
Numeric |
GetDecimal() |
Double |
Double |
Double |
Double
Precision
|
GetDouble()
Note
Vertica Double type uses a default precision of 53.
|
Int64 |
Int64 |
BigInt |
Integer |
GetInt64() |
TimeSpan |
Object |
13 Interval Types |
13 Interval Types |
GetInterval()
Note
There are 13 VerticaType values for the 13 types of intervals. The specific VerticaType used determines the conversion rules that the driver applies. Year/Month intervals represented as 365/30 days
|
String |
String |
Varchar
LongVarChar
|
Varchar
LongVarChar
|
GetString() |
String |
StringFixedLengt |
Char |
Char |
GetString() |
Guid |
Guid |
UUID (see note below) |
UUID |
GetGuid() |
Object |
Object |
N/A |
N/A |
GetValue() |
UUID backwards compatibility
Vertica version 9.0.0 introduced the UUID data type, including JDBC support for UUIDs. The Vertica ADO.NET, ODBC, and OLE DB clients added full support for UUIDs in version 9.0.1. Vertica maintains backwards compatibility with older supported client driver versions that do not support the UUID data type, as follows:
When an older client... |
Vertica... |
Queries tables with UUID columns |
Translates the native UUID values to CHAR values. |
Inserts data into a UUID column |
Converts the CHAR value sent by the client into a native UUID value. |
Queries a UUID column's metadata |
Reports its data type as CHAR. |
2 - Setting the locale for ADO.NET sessions
-
ADO.NET applications use a UTF-16 character set encoding and are responsible for converting any non-UTF-16 encoded data to UTF-16. The same cautions as for ODBC apply if this encoding is violated.
-
The ADO.NET driver converts UTF-16 data to UTF-8 when passing to the Vertica server and converts data sent by Vertica server from UTF-8 to UTF-16.
-
ADO.NET applications should set the correct server session locale by executing the SET LOCALE TO command in order to get expected collation and string functions behavior on the server.
-
If there is no default session locale at the database level, ADO.NET applications need to set the correct server session locale by executing the SET LOCALE TO command in order to get expected collation and string functions behavior on the server. See the SET LOCALE command.
3 - Connecting to the database
3.1 - Using TLS: installing certificates on Windows
You can optionally secure communication between your ADO.NET application and Vertica using TLS.
You can optionally secure communication between your ADO.NET application and Vertica using TLS. The Vertica ADO.NET driver uses the default Windows key store when looking for TLS certificates. This is the same key store that Internet Explorer uses.
Before you can use TLS on the client side, you must implement TLS on the server. See TLS protocol, perform those steps, then return to this topic to install the TLS certificate on Windows.
To use TLS for ADO.NET connections to Vertica:
-
Import the server and client certificates into the Windows Key Store.
-
If required by your certificates, import the public certificate of your Certifying Authority.
Import the server and client certificates into the windows key store:
-
Copy the server.crt file you generated when you enabled TLS on the server to your Windows Machine.
-
Double-click the certificate.
-
Let Windows determine the key type, and click Install.
Import the public certificate of your CA:
You must establish a chain of trust for the certificates. You may need to import the public certificate for your Certifying Authority (CA) (especially if it is a self-signed certificate).
-
Using the same certificate as above, double-click the certificate.
-
Select Place all certificates in the following store.
-
Click Browse, select Trusted Root Certification Authorities and click Next.
-
Click Install.
Enable SSL in your ADO.NET applications
In your connection string, be sure to enable SSL by setting the SSL
property in VerticaConnectionStringBuilder
to true, for example:
//configure connection properties VerticaConnectionStringBuilder builder = new VerticaConnectionStringBuilder();
builder.Host = "192.168.17.10";
builder.Database = "VMart";
builder.User = "dbadmin";
builder.SSL = true;
//open the connection
VerticaConnection _conn = new VerticaConnection(builder.ToString());
_conn.Open();
3.2 - Opening and closing the database connection (ADO.NET)
Before you can access data in Vertica through ADO.NET, you must create a connection to the database using the VerticaConnection class which is an implementation of System.Data.DbConnection.
Before you can access data in Vertica through ADO.NET, you must create a connection to the database using the VerticaConnection class which is an implementation of System.Data.DbConnection. The VerticaConnection class takes a single argument that contains the connection properties as a string. You can manually create a string of property keywords to use as the argument, or you can use the VerticaConnectionStringBuilder class to build a connection string for you.
To download the ADO.NET driver, go to the Client Drivers Downloads page.
This topic details the following:
To manually create a connection string:
See ADO.NET connection properties for a list of available properties to use in your connection string. At a minimum, you need to specify the Host, Database, and User.
-
For each property, provide a value and append the properties and values one after the other, separated by a semicolon. Assign this string to a variable. For example:
String connectString = "DATABASE=VMart;HOST=v_vmart_node0001;USER=dbadmin";
-
Build a Vertica connection object that specifies your connection string.
VerticaConnection _conn = new VerticaConnection(connectString)
-
Open the connection.
_conn.Open();
-
Create a command object and associate it with a connection. All VerticaCommand objects must be associated with a connection.
VerticaCommand command = _conn.CreateCommand();
To use the VerticaConnectionStringBuilder class to create a connection string and open a connection:
-
Create a new object of the VerticaConnectionStringBuilder class.
VerticaConnectionStringBuilder builder = new VerticaConnectionStringBuilder();
-
Update your VerticaConnectionStringBuilder object with property values. See ADO.NET connection properties for a list of available properties to use in your connection string. At a minimum, you need to specify the Host, Database, and User.
builder.Host = "v_vmart_node0001";
builder.Database = "VMart";
builder.User = "dbadmin";
-
Build a Vertica connection object that specifies your connection VerticaConnectionStringBuilder object as a string.
VerticaConnection _conn = new VerticaConnection(builder.ToString());
-
Open the connection.
_conn.Open();
-
Create a command object and associate it with a connection. All VerticaCommand objects must be associated with a connection.
VerticaCommand command = _conn.CreateCommand;
Note
If your database is not in compliance with your Vertica license, the call to
VerticaConnection.open()
returns a warning message to the console and the log. See
Managing licenses for more information.
To close the connection:
When you're finished with the database, close the connection. Failure to close the connection can deteriorate the performance and scalability of your application. It can also prevent other clients from obtaining locks.
_conn.Close();
Example usage:
using System;
using System.Collections.Generic;
using System.Linq;
using System.Text;
using System.Data;
using Vertica.Data.VerticaClient;
namespace ConsoleApplication
{
class Program
{
static void Main(string[] args)
{
VerticaConnectionStringBuilder builder = new VerticaConnectionStringBuilder();
builder.Host = "192.168.1.10";
builder.Database = "VMart";
builder.User = "dbadmin";
VerticaConnection _conn = new VerticaConnection(builder.ToString());
_conn.Open();
//Perform some operations
_conn.Close();
}
}
}
3.3 - ADO.NET connection properties
To download the ADO.NET driver, go to the Client Drivers Downloads page.
To download the ADO.NET driver, go to the Client Drivers Downloads page.
You use connection properties to configure the connection between your ADO.NET client application and your Vertica database. The properties provide the basic information about the connections, such as the server name and port number, needed to connect to your database.
You can set a connection property in two ways:
-
Include the property name and value as part of the connection string you pass to a VerticaConnection
.
-
Set the properties in a VerticaConnectionStringBuilder
object, and then pass the object as a string to a VerticaConnection
.
Property |
Description |
Default Value |
Database |
Name of the Vertica database to which you want to connect. For example, if you installed the example VMart database, the database is "VMart". |
none |
User |
Name of the user to log into Vertica. |
none |
Port |
Port on which Vertica is running. |
5433 |
Host |
The host name or IP address of the server on which Vertica is running.
You can provide an IPv4 address, IPv6 address, or host name.
In mixed IPv4/IPv6 networks, the DNS server configuration determines which IP version address is sent first. Use the PreferredAddressFamily option to force the connection to use either IPv4 or IPv6.
|
none |
PreferredAddressFamily |
The IP version to use if the client and server have both IPv4 and IPv6 addresses and you have provided a host name. Valid values are:
-
Ipv4—Connect to the server using IPv4.
-
Ipv6—Connect to the server using IPv6.
-
None—Use the IP address provided by the DNS server.
|
Vertica.Data.VerticaClient.AddressFamilyPreference.None |
Password |
The password associated with the user connecting to the server. |
string.Empty |
BinaryTransfer |
Provides a Boolean value that, when set to true, uses binary transfer instead of text transfer. When set to false, the ADO.NET connection uses text transfer. Binary transfer provides faster performance in reading data from a server to an ADO.NET client. Binary transfer also requires less bandwidth than text transfer, although it sometimes uses more when transferring a large number of small values.
Binary transfer mode is not backwards compatible to ADO.NET versions earlier than 3.8. If you are using an earlier version, set this value to false.
The data output by both modes is identical with the following exceptions for certain data types:
-
FLOAT: Binary transfer has slightly better precision.
-
TIMESTAMPTZ: Binary transfer can fail to get the session time zone and default to the local time zone, while text transfer reliably uses the session time zone.
-
NUMERIC: Binary transfer is forcibly disabled for NUMERIC data by the server for Vertica 11.0.2+.
|
true |
ConnSettings |
SQL commands to run upon connection. Uses %3B for semicolons. |
string.Empty |
IsolationLevel |
Sets the transaction isolation level for Vertica. See Transactions for a description of the different transaction levels. This value is either Serializable, ReadCommitted, or Unspecified. See Setting the transaction isolation level for an example of setting the isolation level using this keyword.
Note: By default, this value is set to IsolationLevel.Unspecified, which means the connection uses the server's default transaction isolation level. Vertica's default isolation level is IsolationLevel.ReadCommitted.
|
System.Data. IsolationLevel.Unspecified |
Label |
A string to identify the session on the server. |
string |
DirectBatchInsert |
Deprecated |
true |
ResultBufferSize |
The size of the buffer to use when streaming results. A value of 0 means ResultBufferSize is turned off. |
8192 |
ConnectionTimeout |
Number seconds to wait for a connection. A value of 0 means no timeout. |
0 |
ReadOnly |
A Boolean value. If true, throw an exception on write attempts. |
false |
Pooling |
A boolean value, whether to enable connection pooling. Connection pooling is useful for server applications because it allows the server to reuse connections. This saves resources and enhances the performance of executing commands on the database. It also reduces the amount of time a user must wait to establish a connection to the database |
false |
MinPoolSize |
An integer that defines the minimum number of connections to pool.
Valid Values: Cannot be greater than the number of connections that the server is configured to allow. Otherwise, an exception results.
Default: 55
|
1 |
MaxPoolSize |
An integer that defines the maximum number of connections to pool.
Valid Values: Cannot be greater than the number of connections that the server is configured to allow. Otherwise, an exception results.
|
20 |
LoadBalanceTimeout |
The amount of time, expressed in seconds, to timeout or remove unused pooled connections.
**Disable: **Set to 0 (no timeouts)
If you are using a cluster environment to load-balance the work, then pool is restricted to the servers in the cluster when the pool was created. If additional servers are added to the cluster, and the pool is not removed, then the new servers are never added to the connection pool unless LoadBalanceTimeout is set and exceeded or VerticaConnection.ClearAllPools() is called manually from an application. If you are using load balancing, then set this property to a value that considers when new servers are added to the cluster. However, do not set it so low that pools are frequently removed and rebuilt, doing so makes pooling ineffective.
|
0 (no timeout) |
SSL |
A Boolean value, indicating whether to use SSL for the connection. |
false |
IntegratedSecurity |
Provides a Boolean value that, when set to true, uses the user’s Windows credentials for authentication, instead of user/password in the connection string. |
false |
KerberosServiceName |
Provides the service name portion of the Vertica Kerberos principal; for example: vertica/host@EXAMPLE.COM |
vertica |
KerberosHostname |
Provides the instance or host name portion of the Vertica Kerberos principal; for example: vertica/host@EXAMPLE.COM |
Value specified in the servername connection string property |
3.4 - Load balancing in ADO.NET
Native connection load balancing
Native connection load balancing helps spread the overhead caused by client connections on the hosts in the Vertica database. Both the server and the client must enable native connection load balancing. If enabled by both, then when the client initially connects to a host in the database, the host picks a host to handle the client connection from a list of the currently up hosts in the database, and informs the client which host it has chosen.
If the initially-contacted host does not choose itself to handle the connection, the client disconnects, then opens a second connection to the host selected by the first host. The connection process to this second host proceeds as usual—if SSL is enabled, then SSL negotiations begin, otherwise the client begins the authentication process. See About native connection load balancing for details.
To enable native load balancing on your client, set the ConnectionLoadBalance
connection parameter to true either in the connection string or using the ConnectionStringBuilder()
. The following example demonstrates connecting to the database several times with native connection load balancing enabled, and fetching the name of the node handling the connection from the V_MONITOR.CURRENT_SESSION system table.
using System;
using System.Text;
using System.Data;
using Vertica.Data.VerticaClient;
namespace ConsoleApplication1 {
class Program {
static void Main(string[] args) {
VerticaConnectionStringBuilder builder = new VerticaConnectionStringBuilder();
builder.Host = "v_vmart_node0001.example.com";
builder.Database = "VMart";
builder.User = "dbadmin";
// Enable native client load balancing in the client,
// must also be enabled on the server!
builder.ConnectionLoadBalance = true;
// Connect 3 times to verify a new node is connected
// for each connection.
for (int i = 1; i <= 4; i++) {
try {
VerticaConnection _conn = new VerticaConnection(builder.ToString());
_conn.Open();
if (i == 1) {
// On the first connection, check the server policy for load balance
VerticaCommand sqlcom = _conn.CreateCommand();
sqlcom.CommandText = "SELECT LOAD_BALANCE_POLICY FROM V_CATALOG.DATABASES";
var returnValue = sqlcom.ExecuteScalar();
Console.WriteLine("Status of load balancy policy
on server: " + returnValue.ToString() + "\n");
}
VerticaCommand command = _conn.CreateCommand();
command.CommandText = "SELECT node_name FROM V_MONITOR.CURRENT_SESSION";
VerticaDataReader dr = command.ExecuteReader();
while (dr.Read()) {
Console.Write("Connect attempt #" + i + "... ");
Console.WriteLine("Connected to node " + dr[0]);
}
dr.Close();
_conn.Close();
Console.WriteLine("Disconnecting.\n");
}
catch(Exception e) {
Console.WriteLine(e.Message);
}
}
}
}
}
Running the above example produces the following output:
Status of load balancing policy on server: roundrobin
Connect attempt #1... Connected to node v_vmart_node0001
Disconnecting.
Connect attempt #2... Connected to node v_vmart_node0002
Disconnecting.
Connect attempt #3... Connected to node v_vmart_node0003
Disconnecting.
Connect attempt #4... Connected to node v_vmart_node0001
Disconnecting.
Hostname-based load balancing
You can also balance workloads by resolving a single hostname to multiple IP addresses. The ADO.NET client driver load balances by automatically resolving the hostname to one of the specified IP addresses at random.
For example, suppose the hostname verticahost.example.com
has the following entries in C:\Windows\System32\drivers\etc\hosts
:
192.0.2.0 verticahost.example.com
192.0.2.1 verticahost.example.com
192.0.2.2 verticahost.example.com
Specifying the hostname verticahost.example.com
randomly resolves to one of the listed IP addresses.
3.5 - ADO.NET connection failover
If a client application attempts to connect to a host in the Vertica cluster that is down, the connection attempt fails when using the default connection configuration. This failure usually returns an error to the user. The user must either wait until the host recovers and retry the connection or manually edit the connection settings to choose another host.
Due to Vertica Analytic Database's distributed architecture, you usually do not care which database host handles a client application's connection. You can use the client driver's connection failover feature to prevent the user from getting connection errors when the host specified in the connection settings is unreachable. The JDBC driver gives you several ways to let the client driver automatically attempt to connect to a different host if the one specified in the connection parameters is unreachable:
-
Configure your DNS server to return multiple IP addresses for a host name. When you use this host name in the connection settings, the client attempts to connect to the first IP address from the DNS lookup. If the host at that IP address is unreachable, the client tries to connect to the second IP, and so on until it either manages to connect to a host or it runs out of IP addresses.
-
Supply a list of backup hosts for the client driver to try if the primary host you specify in the connection parameters is unreachable.
-
(JDBC only) Use driver-specific connection properties to manage timeouts before attempting to connect to the next node.
For all methods, the process of failover is transparent to the client application (other than specifying the list of backup hosts, if you choose to use the list method of failover). If the primary host is unreachable, the client driver automatically tries to connect to other hosts.
Failover only applies to the initial establishment of the client connection. If the connection breaks, the driver does not automatically try to reconnect to another host in the database.
Choosing a failover method
You usually choose to use one of the two failover methods. However, they do work together. If your DNS server returns multiple IP addresses and you supply a list of backup hosts, the client first tries all of the IPs returned by the DNS server, then the hosts in the backup list.
Note
If a host name in the backup host list resolves to multiple IP addresses, the client does not try all of them. It just tries the first IP address in the list.
The DNS method of failover centralizes the configuration client failover. As you add new nodes to your Vertica Analytic Database cluster, you can choose to add them to the failover list by editing the DNS server settings. All client systems that use the DNS server to connect to Vertica Analytic Database automatically use connection failover without having to change any settings. However, this method does require administrative access to the DNS server that all clients use to connect to the Vertica Analytic Database cluster. This may not be possible in your organization.
Using the backup server list is easier than editing the DNS server settings. However, it decentralizes the failover feature. You may need to update the application settings on each client system if you make changes to your Vertica Analytic Database cluster.
Using DNS failover
To use DNS failover, you need to change your DNS server's settings to map a single host name to multiple IP addresses of hosts in your Vertica Analytic Database cluster. You then have all client applications use this host name to connect to Vertica Analytic Database.
You can choose to have your DNS server return as many IP addresses for the host name as you want. In smaller clusters, you may choose to have it return the IP addresses of all of the hosts in your cluster. However, for larger clusters, you should consider choosing a subset of the hosts to return. Otherwise there can be a long delay as the client driver tries unsuccessfully to connect to each host in a database that is down.
Using the backup host list
To enable backup list-based connection failover, your client application has to specify at least one IP address or host name of a host in the BackupServerNode
parameter. The host name or IP can optionally be followed by a colon and a port number. If not supplied, the driver defaults to the standard Vertica port number (5433). To list multiple hosts, separate them by a comma.
The following example demonstrates setting the BackupServerNode
connection parameter to specify additional hosts for the connection attempt. The connection string intentionally has a non-existent node, so that the initial connection fails. The client driver has to resort to trying the backup hosts to establish a connection to Vertica.
using System;
using System.Text;
using System.Data;
using Vertica.Data.VerticaClient;
namespace ConsoleApplication1
{
class Program
{
static void Main(string[] args)
{
VerticaConnectionStringBuilder builder =
new VerticaConnectionStringBuilder();
builder.Host = "not.a.real.host:5433";
builder.Database = "VMart";
builder.User = "dbadmin";
builder.BackupServerNode =
"another.broken.node:5433,v_vmart_node0002.example.com:5433";
try
{
VerticaConnection _conn =
new VerticaConnection(builder.ToString());
_conn.Open();
VerticaCommand sqlcom = _conn.CreateCommand();
sqlcom.CommandText = "SELECT node_name FROM current_session";
var returnValue = sqlcom.ExecuteScalar();
Console.WriteLine("Connected to node: " +
returnValue.ToString() + "\n");
_conn.Close();
Console.WriteLine("Disconnecting.\n");
}
catch (Exception e)
{
Console.WriteLine(e.Message);
}
}
}
}
Notes
-
When native connection load balancing is enabled, the additional servers specified in the BackupServerNode connection parameter are only used for the initial connection to a Vertica host. If host redirects the client to another host in the database cluster to handle its connection request, the second connection does not use the backup node list. This is rarely an issue, since native connection load balancing is aware of which nodes are currently up in the database. See Load balancing in ADO.NET.
-
Connections to a host taken from the BackupServerNode list are not pooled for ADO.NET connections.
3.6 - Configuring log properties (ADO.Net)
Log properties for ADO.Net are configured differently than they are other client drivers.
Log properties for ADO.Net are configured differently than they are other client drivers. On the other client drivers, log properties can be configured as one of the connection properties. The ADO.Net driver user the VerticaLogProperties class to configure the properties.
VerticaLogProperties
VerticaLogProperties is a static class that allows you to set and get the log settings for the ADO.net driver. You can control the log level, log path, and log namespace using this class.
The log is created when the first connection is opened. Once the connection is opened, you cannot change the log path. It must be set prior to opening the connection. You can change the log level and log namespace at any time.
Setting log properties
Setting the log properties is done using the three methods in the VerticaLogProperties class. The three methods are:
-
SetLogPath(String path, bool persist)
-
SetLogNamespace(String lognamespace, bool persist)
-
SetLogLevel(VerticaLogLevel loglevel, bool persist)
Each of the methods requires a boolean persist argument. When set to true, the persist argument causes the setting to be written to the client's Windows Registry, where it is used for all subsequent connections. If set to false, then the log property only applies to the current session.
SetLogPath
The SetLogPath method takes as its arguments a string containing the path to the log file and the persist argument. If the path string contains only a directory path, then the log file is created with the name vdp-driver-MM-dd_HH.mm.ss.log (where MM-dd_HH.mm.ss is the date and time the log was created). If the path ends in a filename, such as log.txt or log.log, then the log is created with that filename.
If SetLogPath is called with an empty string for the path argument, then the client executable's current directory is used as the log path.
If SetLogPath is not called and no registry entry exists for the log path, and you have called any of the other VerticaLogProperties methods, then the client executable's current directory is used as the log path.
When the persist argument is set to true, the path specified is copied to the registry verbatim. If no filename was specified, then the filename is not saved to the registry.
Note
Note: The path must exist on the client system prior to calling this method. The method does not create directories.
Example Usage:
//set the log path
string path = "C:\\log";
VerticaLogProperties.SetLogPath(path, false);
SetLogNamespace
The SetLogNamespace method takes as its arguments a string containing the namespace to log and the persist argument. The namespace string to log can be one of the following:
-
Vertica
-
Vertica.Data.VerticaClient
-
Vertica.Data.Internal.IO
-
Vertica.Data.Internal.DataEngine
-
Vertica.Data.Internal.Core
Namespaces can be truncated to include multiple child namespaces. For example, you can specify "Vertica.Data.Internal" to log for all of the Vertica.Data.Internal namespaces.
If a log namespace is not set, and no value is stored in the registry, then the "Vertica" namespace is used for logging.
Example Usage:
//set namespace to log
string lognamespace = "Vertica.Data.VerticaClient";
VerticaLogProperties.SetLogNamespace(lognamespace, false);
SetLogLevel
The SetLogLevel method takes as its arguments a VerticaLogLevel type and the persist argument. The VerticaLogLevel argument can be one of:
-
VerticaLogLevel.None
-
VerticaLogLevel.Fatal
-
VerticaLogLevel.Error
-
VerticaLogLevel.Warning
-
VerticaLogLevel.Info
-
VerticaLogLevel.Debug
-
VerticaLogLevel.Trace
If a log level is not set, and no value is stored in the registry, then VerticaLogLevel.None is used.
Example Usage:
//set log level
VerticaLogLevel level = VerticaLogLevel.Debug;
VerticaLogProperties.SetLogLevel(level, false);
Getting log properties
You can get the log property values using the getters included in the VerticaLogProperties class. The properties are:
-
LogPath
-
LogNamespace
-
LogLevel
Example Usage:
//get current log settings
string logpath = VerticaLogProperties.LogPath;
VerticaLogLevel loglevel = VerticaLogProperties.LogLevel;
string logns = VerticaLogProperties.LogNamespace;
Console.WriteLine("Current Log Settings:");
Console.WriteLine("Log Path: " + logpath);
Console.WriteLine("Log Level: " + loglevel);
Console.WriteLine("Log Namespace: " + logns);
Setting and getting log properties example
This complete example shows how to set and get log properties:
using System;
using System.Collections.Generic;
using System.Linq;
using System.Text;
using System.Data;
using Vertica.Data.VerticaClient;
namespace ConsoleApplication
{
class Program
{
static void Main(string[] args)
{
//configure connection properties
VerticaConnectionStringBuilder builder = new VerticaConnectionStringBuilder();
builder.Host = "192.168.1.10";
builder.Database = "VMart";
builder.User = "dbadmin";
//get current log settings
string logpath = VerticaLogProperties.LogPath;
VerticaLogLevel loglevel = VerticaLogProperties.LogLevel;
string logns = VerticaLogProperties.LogNamespace;
Console.WriteLine("\nOld Log Settings:");
Console.WriteLine("Log Path: " + logpath);
Console.WriteLine("Log Level: " + loglevel);
Console.WriteLine("Log Namespace: " + logns);
//set the log path
string path = "C:\\log";
VerticaLogProperties.SetLogPath(path, false);
//set log level
VerticaLogLevel level = VerticaLogLevel.Debug;
VerticaLogProperties.SetLogLevel(level, false);
//set namespace to log
string lognamespace = "Vertica";
VerticaLogProperties.SetLogNamespace(lognamespace, false);
//open the connection
VerticaConnection _conn = new VerticaConnection(builder.ToString());
_conn.Open();
//get new log settings
logpath = VerticaLogProperties.LogPath;
loglevel = VerticaLogProperties.LogLevel;
logns = VerticaLogProperties.LogNamespace;
Console.WriteLine("\nNew Log Settings:");
Console.WriteLine("Log Path: " + logpath);
Console.WriteLine("Log Level: " + loglevel);
Console.WriteLine("Log Namespace: " + logns);
//close the connection
_conn.Close(); }
}
}
The example produces the following output:
Old Log Settings:
Log Path:
Log Level: None
Log Namespace:
New Log Settings:
Log Path: C:\log
Log Level: Debug
Log Namespace: Vertica
4 - Querying the database using ADO.NET
This section describes how to create queries to do the following:.
This section describes how to create queries to do the following:
Note
The ExecuteNonQuery() method used to query the database returns an int32 with the number of rows affected by the query. The maximum size of an int32 type is a constant and is defined to be 2,147,483,547. If your query returns more results than the int32 max, then ADO.NET throws an exception because of the overflow of the int32 type. However the query is still processed by Vertica even when the reporting of the return value fails. This is a limitation in .NET, as ExecuteNonQuery() is part of the standard ADO.NET interface.
4.1 - Inserting data (ADO.NET)
Inserting data can done using the VerticaCommand class.
Inserting data can done using the VerticaCommand class. VerticaCommand is an implementation of DbCommand. It allows you to create and send a SQL statement to the database. Use the CommandText method to assign a SQL statement to the command and then execute the SQL by calling the ExecuteNonQuery method. The ExecuteNonQuery method is used for executing statements that do not return result sets.
To insert a single row of data:
-
Create a connection to the database.
-
Create a command object using the connection.
VerticaCommand command = _conn.CreateCommand();
-
Insert data using an INSERT statement. The following is an example of a simple insert. Note that is does not contain a COMMIT statement because the Vertica ADO.NET driver operates in autocommit mode.
command.CommandText =
"INSERT into test values(2, 'username', 'email', 'password')";
-
Execute the query. The rowsAdded variable contains the number of rows added by the insert statement.
Int32 rowsAdded = command.ExecuteNonQuery();
The ExecuteNonQuery() method returns the number of rows affected by the command for UPDATE, INSERT, and DELETE statements. For all other types of statements it returns -1. If a rollback occurs then it is also set to -1.
Example usage:
using System;
using System.Collections.Generic;
using System.Linq;
using System.Text;
using System.Data;
using Vertica.Data.VerticaClient;
namespace ConsoleApplication
{
class Program
{
static void Main(string[] args)
{
VerticaConnectionStringBuilder builder = new VerticaConnectionStringBuilder();
builder.Host = "192.168.1.10";
builder.Database = "VMart";
builder.User = "dbadmin";
VerticaConnection _conn = new VerticaConnection(builder.ToString());
_conn.Open();
VerticaCommand command = _conn.CreateCommand();
command.CommandText =
"INSERT into test values(2, 'username', 'email', 'password')";
Int32 rowsAdded = command.ExecuteNonQuery();
Console.WriteLine( rowsAdded + " rows added!");
_conn.Close();
}
}
}
4.1.1 - Using parameters
You can use parameters to execute similar SQL statements repeatedly and efficiently.
You can use parameters to execute similar SQL statements repeatedly and efficiently.
Using parameters
VerticaParameters are an extension of the System.Data.DbParameter base class in ADO.NET and are used to set parameters in commands sent to the server. Use Parameters in all queries (SELECT/INSERT/UPDATE/DELETE) for which the values in the WHERE clause are not static; that is for all queries that have a known set of columns, but whose filter criteria is set dynamically by an application or end user. Using parameters in this way greatly decreases the chances of a SQL injection issue that can occur when simply creating a SQL query from a number of variables.
Parameters require that a valid DbType, VerticaDbType, or System type be assigned to the parameter. See Data types and ADO.NET data types for a mapping of System, Vertica, and DbTypes.
To create a parameter placeholder, place either the at sign (@) or a colon (:) character in front of the parameter name in the actual query string. Do not insert any spaces between the placeholder indicator (@ or :) and the placeholder.
Note
The @ character is the preferred way to identify parameters. The colon (:) character is supported for backward compatibility.
For example, the following typical query uses the string 'MA' as a filter.
SELECT customer_name, customer_address, customer_city, customer_state
FROM customer_dimension WHERE customer_state = 'MA';
Instead, the query can be written to use a parameter. In the following example, the string MA is replaced by the parameter placeholder @STATE.
SELECT customer_name, customer_address, customer_city, customer_state
FROM customer_dimension WHERE customer_state = @STATE;
For example, the ADO.net code for the prior example would be written as:
VerticaCommand command = _conn.CreateCommand();
command.CommandText = “SELECT customer_name, customer_address, customer_city, customer_state
FROM customer_dimension WHERE customer_state = @STATE”;
command.Parameters.Add(new VerticaParameter( “STATE”, VerticaType.VarChar));
command.Parameters["STATE"].Value = "MA";
Note
Although the VerticaCommand class supports a Prepare() method, you do not need to call the Prepare() method for parameterized statements because Vertica automatically prepares the statement for you.
4.1.2 - Creating and rolling back transactions
Transactions in Vertica are atomic, consistent, isolated, and durable.
Creating transactions
Transactions in Vertica are atomic, consistent, isolated, and durable. When you connect to a database using the Vertica ADO.NET Driver, the connection is in autocommit mode and each individual query is committed upon execution. You can collect multiple statements into a single transaction and commit them at the same time by using a transaction. You can also choose to rollback a transaction before it is committed if your code determines that a transaction should not commit.
Transactions use the VerticaTransaction object, which is an implementation of DbTransaction. You must associate the transaction with the VerticaCommand object.
The following code uses an explicit transaction to insert one row each into to tables of the VMart schema.
To create a transaction in Vertica using the ADO.NET driver:
-
Create a connection to the database.
-
Create a command object using the connection.
VerticaCommand command = _conn.CreateCommand();
-
Start an explicit transaction, and associate the command with it.
VerticaTransaction txn = _conn.BeginTransaction();
command.Connection = _conn;
command.Transaction = txn;
-
Execute the individual SQL statements to add rows.
command.CommandText =
"insert into product_dimension values( ... )";
command.ExecuteNonQuery();
command.CommandText =
"insert into store_orders_fact values( ... )";
-
Commit the transaction.
txn.Commit();
Rolling back transactions
If your code checks for errors, then you can catch the error and rollback the entire transaction.
VerticaTransaction txn = _conn.BeginTransaction();
VerticaCommand command = new
VerticaCommand("insert into product_dimension values( 838929, 5, 'New item 5' )", _conn);
// execute the insert
command.ExecuteNonQuery();
command.CommandText = "insert into product_dimension values( 838929, 6, 'New item 6' )";
// try insert and catch any errors
bool error = false;
try
{
command.ExecuteNonQuery();
}
catch (Exception e)
{
Console.WriteLine(e.Message);
error = true;
}
if (error)
{
txn.Rollback();
Console.WriteLine("Errors. Rolling Back.");
}
else
{
txn.Commit();
Console.WriteLine("Queries Successful. Committing.");
}
Commit and rollback example
This example details how you can commit or rollback queries during a transaction.
using System;
using System.Collections.Generic;
using System.Linq;
using System.Text;
using System.Data;
using Vertica.Data.VerticaClient;
namespace ConsoleApplication
{
class Program
{
static void Main(string[] args)
{
VerticaConnectionStringBuilder builder = new VerticaConnectionStringBuilder();
builder.Host = "192.168.1.10";
builder.Database = "VMart";
builder.User = "dbadmin";
VerticaConnection _conn = new VerticaConnection(builder.ToString());
_conn.Open();
bool error = false;
VerticaCommand command = _conn.CreateCommand();
VerticaCommand command2 = _conn.CreateCommand();
VerticaTransaction txn = _conn.BeginTransaction();
command.Connection = _conn;
command.Transaction = txn;
command.CommandText =
"insert into test values(1, 'test', 'test', 'test' )";
Console.WriteLine(command.CommandText);
try
{
command.ExecuteNonQuery();
}
catch (Exception e)
{
Console.WriteLine(e.Message);
error = true;
}
command.CommandText =
"insert into test values(2, 'ear', 'eye', 'nose', 'extra' )";
Console.WriteLine(command.CommandText);
try
{
command.ExecuteNonQuery();
}
catch (Exception e)
{
Console.WriteLine(e.Message);
error = true;
}
if (error)
{
txn.Rollback();
Console.WriteLine("Errors. Rolling Back.");
}
else
{
txn.Commit();
Console.WriteLine("Queries Successful. Committing.");
}
_conn.Close();
}
}
}
The example displays the following output on the console:
insert into test values(1, 'test', 'test', 'test' )
insert into test values(2, 'ear', 'eye', 'nose', 'extra' )
[42601]ERROR: INSERT has more expressions than target columns
Errors. Rolling Back.
See also
4.1.2.1 - Setting the transaction isolation level
You can set the transaction isolation level on a per-connection and per-transaction basis.
You can set the transaction isolation level on a per-connection and per-transaction basis. See Transaction for an overview of the transaction isolation levels supported in Vertica. To set the default transaction isolation level for a connection, use the IsolationLevel
keyword in the VerticaConnectionStringBuilder string (see Connection String Keywords for details). To set the isolation level for an individual transaction, pass the isolation level to the VerticaConnection.BeginTransaction()
method call to start the transaction.
To set the isolation level on a connection-basis:
-
Use the VerticaConnectionStringBuilder to build the connection string.
-
Provide a value for the IsolationLevel builder string. It can take one of two values: IsolationLevel.ReadCommited (default) or IsolationLevel.Serializeable. For example:
VerticaConnectionStringBuilder builder = new VerticaConnectionStringBuilder();
builder.Host = "192.168.1.100";
builder.Database = "VMart";
builder.User = "dbadmin";
builder.IsolationLevel = System.Data.IsolationLevel.Serializeable
VerticaConnection _conn1 = new VerticaConnection(builder.ToString());
_conn1.Open();
To set the isolation level on a transaction basis:
-
Set the IsolationLevel on the BeginTransaction method, for example
VerticaTransaction txn = _conn.BeginTransaction(IsolationLevel.Serializable);
Example usage:
The following example demonstrates:
-
getting the connection's transaction isolation level.
-
setting the connection's isolation level using connection property.
-
setting the transaction isolation level for a new transaction.
using System;
using System.Collections.Generic;
using System.Linq;
using System.Text;
using System.Data;
Vertica.Data.VerticaClient;
namespace ConsoleApplication
{
class Program
{
static void Main(string[] args)
{
VerticaConnectionStringBuilder builder = new VerticaConnectionStringBuilder();
builder.Host = "192.168.1.10";
builder.Database = "VMart";
builder.User = "dbadmin";
VerticaConnection _conn1 = new VerticaConnection(builder.ToString());
_conn1.Open();
VerticaTransaction txn1 = _conn1.BeginTransaction();
Console.WriteLine("\n Transaction 1 Transaction Isolation Level: " +
txn1.IsolationLevel.ToString());
txn1.Rollback();
VerticaTransaction txn2 = _conn1.BeginTransaction(IsolationLevel.Serializable);
Console.WriteLine("\n Transaction 2 Transaction Isolation Level: " +
txn2.IsolationLevel.ToString());
txn2.Rollback();
VerticaTransaction txn3 = _conn1.BeginTransaction(IsolationLevel.ReadCommitted);
Console.WriteLine("\n Transaction 3 Transaction Isolation Level: " +
txn3.IsolationLevel.ToString());
_conn1.Close();
}
}
}
When run, the example code prints the following to the system console:
Transaction 1 Transaction Isolation Level: ReadCommitted
Transaction 2 Transaction Isolation Level: Serializable
Transaction 3 Transaction Isolation Level: ReadCommitted
4.2 - Reading data (ADO.Net)
To read data from the database use VerticaDataReader, an implementation of DbDataReader.
To read data from the database use VerticaDataReader, an implementation of DbDataReader. This implementation is useful for moving large volumes of data quickly off the server where it can be run through analytic applications.
Note
A VerticaCommand cannot execute anything else while it has an open VerticaDataReader associated with it. To execute something else, close the data reader or use a different VerticaCommand object.
To read data from the database using VerticaDataReader:
-
Create a connection to the database.
-
Create a command object using the connection.
VerticaCommand command = _conn.CreateCommand();
-
Create a query. This query works with the example VMart database.
command.CommandText =
"SELECT fat_content, product_description " +
"FROM (SELECT DISTINCT fat_content, product_description" +
" FROM product_dimension " +
" WHERE department_description " + " IN ('Dairy') " +
" ORDER BY fat_content) AS food " +
"LIMIT 10;";
-
Execute the reader to return the results from the query. The following command calls the ExecuteReader method of the VerticaCommand object to obtain the VerticaDataReader object.
VerticaDataReader dr = command.ExecuteReader();
-
Read the data. The data reader returns results in a sequential stream. Therefore, you must read data from tables row-by-row. The following example uses a while loop to accomplish this:
Console.WriteLine("\n\n Fat Content\t Product Description");
Console.WriteLine("------------\t -------------------");
int rows = 0;
while (dr.Read())
{
Console.WriteLine(" " + dr[0] + " \t " + dr[1]);
++rows;
}
Console.WriteLine("------------\n (" + rows + " rows)\n");
-
When you're finished, close the data reader to free up resources.
dr.Close();
Example usage:
using System;
using System.Collections.Generic;
using System.Linq;
using System.Text;
using System.Data;
using Vertica.Data.VerticaClient;
namespace ConsoleApplication
{
class Program
{
static void Main(string[] args)
{
VerticaConnectionStringBuilder builder = new VerticaConnectionStringBuilder();
builder.Host = "192.168.1.10";
builder.Database = "VMart";
builder.User = "dbadmin";
VerticaConnection _conn = new VerticaConnection(builder.ToString());
_conn.Open();
VerticaCommand command = _conn.CreateCommand();
command.CommandText =
"SELECT fat_content, product_description " +
"FROM (SELECT DISTINCT fat_content, product_description" +
" FROM product_dimension " +
" WHERE department_description " +
" IN ('Dairy') " +
" ORDER BY fat_content) AS food " +
"LIMIT 10;";
VerticaDataReader dr = command.ExecuteReader();
Console.WriteLine("\n\n Fat Content\t Product Description");
Console.WriteLine("------------\t -------------------");
int rows = 0;
while (dr.Read())
{
Console.WriteLine(" " + dr[0] + " \t " + dr[1]);
++rows;
}
Console.WriteLine("------------\n (" + rows + " rows)\n");
dr.Close();
_conn.Close();
}
}
}
4.3 - Loading data through ADO.Net
This section details the different ways that you can load data in Vertica using the ADO.NET client driver:.
This section details the different ways that you can load data in Vertica using the ADO.NET client driver:
4.3.1 - Using the Vertica data adapter
The Vertica data adapter (VerticaDataAdapter) enables a client to exchange data between a data set and a Vertica database.
The Vertica data adapter (VerticaDataAdapter) enables a client to exchange data between a data set and a Vertica database. It is an implementation of DbDataAdapter. You can use VerticaDataAdapter to simply read data, or, for example, read data from a database into a data set, and then write changed data from the data set back to the database.
Batching updates
When using the Update() method to update a dataset, you can optionally use the UpdateBatchSize() method prior to calling Update() to reduce the number of times the client communicates with the server to perform the update. The default value of UpdateBatchSize is 1. If you have multiple rows.Add() commands for a data set, then you can change the batch size to an optimal size to speed up the operations your client must perform to complete the update.
Reading data from Vertica using the data adapter:
The following example details how to perform a select query on the VMart schema and load the result into a DataTable, then output the contents of the DataTable to the console.
using System;
using System.Collections.Generic;
using System.Linq;
using System.Text;
using System.Data;
using System.Data.SqlClient;
Vertica.Data.VerticaClient;
namespace ConsoleApplication
{
class Program
{
static void Main(string[] args)
{
VerticaConnectionStringBuilder builder = new VerticaConnectionStringBuilder();
builder.Host = "192.168.1.10";
builder.Database = "VMart";
builder.User = "dbadmin";
VerticaConnection _conn = new VerticaConnection(builder.ToString());
_conn.Open();
// Try/Catch any exceptions
try
{
using (_conn)
{
// Create the command
VerticaCommand command = _conn.CreateCommand();
command.CommandText = "select product_key, product_description " +
"from product_dimension where product_key < 10";
// Associate the command with the connection
command.Connection = _conn;
// Create the DataAdapter
VerticaDataAdapter adapter = new VerticaDataAdapter();
adapter.SelectCommand = command;
// Fill the DataTable
DataTable table = new DataTable();
adapter.Fill(table);
// Display each row and column value.
int i = 1;
foreach (DataRow row in table.Rows)
{
foreach (DataColumn column in table.Columns)
{
Console.Write(row[column] + "\t");
}
Console.WriteLine();
i++;
}
Console.WriteLine(i + " rows returned.");
}
}
catch (Exception e)
{
Console.WriteLine(e.Message);
}
_conn.Close();
}
}
}
Reading data from Vertica into a data set and changing data:
The following example shows how to use a data adapter to read from and insert into a dimension table of the VMart schema.
using System;
using System.Collections.Generic;
using System.Linq;
using System.Text;
using System.Data;
using System.Data.SqlClient;
using Vertica.Data.VerticaClient
namespace ConsoleApplication
{
class Program
{
static void Main(string[] args)
{
VerticaConnectionStringBuilder builder = new VerticaConnectionStringBuilder();
builder.Host = "192.168.1.10";
builder.Database = "VMart";
builder.User = "dbadmin";
VerticaConnection _conn = new VerticaConnection(builder.ToString());
_conn.Open();
// Try/Catch any exceptions
try
{
using (_conn)
{
//Create a data adapter object using the connection
VerticaDataAdapter da = new VerticaDataAdapter();
//Create a select statement that retrieves data from the table
da.SelectCommand = new
VerticaCommand("select * from product_dimension where product_key < 10",
_conn);
//Set up the insert command for the data adapter, and bind variables for some of the columns
da.InsertCommand = new
VerticaCommand("insert into product_dimension values( :key, :version, :desc )",
_conn);
da.InsertCommand.Parameters.Add(new VerticaParameter("key", VerticaType.BigInt));
da.InsertCommand.Parameters.Add(new VerticaParameter("version", VerticaType.BigInt));
da.InsertCommand.Parameters.Add(new VerticaParameter("desc", VerticaType.VarChar));
da.InsertCommand.Parameters[0].SourceColumn = "product_key";
da.InsertCommand.Parameters[1].SourceColumn = "product_version";
da.InsertCommand.Parameters[2].SourceColumn = "product_description";
da.TableMappings.Add("product_key", "product_key");
da.TableMappings.Add("product_version", "product_version");
da.TableMappings.Add("product_description", "product_description");
//Create and fill a Data set for this dimension table, and get the resulting DataTable.
DataSet ds = new DataSet();
da.Fill(ds, 0, 0, "product_dimension");
DataTable dt = ds.Tables[0];
//Bind parameters and add two rows to the table.
DataRow dr = dt.NewRow();
dr["product_key"] = 838929;
dr["product_version"] = 5;
dr["product_description"] = "New item 5";
dt.Rows.Add(dr);
dr = dt.NewRow();
dr["product_key"] = 838929;
dr["product_version"] = 6;
dr["product_description"] = "New item 6";
dt.Rows.Add(dr);
//Extract the changes for the added rows.
DataSet ds2 = ds.GetChanges();
//Send the modifications to the server.
int updateCount = da.Update(ds2, "product_dimension");
//Merge the changes into the original Data set, and mark it up to date.
ds.Merge(ds2);
ds.AcceptChanges();
Console.WriteLine(updateCount + " updates made!");
}
}
catch (Exception e)
{
Console.WriteLine(e.Message);
}
_conn.Close();
}
}
}
4.3.2 - Using batch inserts and prepared statements
You can load data in batches using a prepared statement with parameters.
You can load data in batches using a prepared statement with parameters. You can also use transactions to rollback the batch load if any errors are encountered.
If you are loading large batches of data (more than 100MB), then consider using a direct batch insert.
The following example details using data contained in arrays, parameters, and a transaction to batch load data.
The test table used in the example is created with the command:
=> CREATE TABLE test (id INT, username VARCHAR(24), email VARCHAR(64), password VARCHAR(8));
Example batch insert using parameters and transactions
using System;
using System.Collections.Generic;
using System.Linq;
using System.Text;
using System.Data;
using Vertica.Data.VerticaClient;
namespace ConsoleApplication
{
class Program
{
static void Main(string[] args)
{
VerticaConnectionStringBuilder builder = new VerticaConnectionStringBuilder();
builder.Host = "192.168.1.10";
builder.Database = "VMart";
builder.User = "dbadmin";
VerticaConnection _conn = new VerticaConnection(builder.ToString());
_conn.Open();
// Create arrays for column data
int[] ids = {1, 2, 3, 4};
string[] usernames = {"user1", "user2", "user3", "user4"};
string[] emails = { "user1@example.com", "user2@example.com","user3@example.com","user4@example.com" };
string[] passwords = { "pass1", "pass2", "pass3", "pass4" };
// create counters for accepted and rejected rows
int rows = 0;
int rejRows = 0;
bool error = false;
// Create the transaction
VerticaTransaction txn = _conn.BeginTransaction();
// Create the parameterized query and assign parameter types
VerticaCommand command = _conn.CreateCommand();
command.CommandText = "insert into TEST values (@id, @username, @email, @password)";
command.Parameters.Add(new VerticaParameter("id", VerticaType.BigInt));
command.Parameters.Add(new VerticaParameter("username", VerticaType.VarChar));
command.Parameters.Add(new VerticaParameter("email", VerticaType.VarChar));
command.Parameters.Add(new VerticaParameter("password", VerticaType.VarChar));
// Prepare the statement
command.Prepare();
// Loop through the column arrays and insert the data
for (int i = 0; i < ids.Length; i++) {
command.Parameters["id"].Value = ids[i];
command.Parameters["username"].Value = usernames[i];
command.Parameters["email"].Value = emails[i];
command.Parameters["password"].Value = passwords[i];
try
{
rows += command.ExecuteNonQuery();
}
catch (Exception e)
{
Console.WriteLine("\nInsert failed - \n " + e.Message + "\n");
++rejRows;
error = true;
}
}
if (error)
{
// Roll back if errors
Console.WriteLine("Errors. Rolling Back Transaction.");
Console.WriteLine(rejRows + " rows rejected.");
txn.Rollback();
}
else
{
// Commit if no errors
Console.WriteLine("No Errors. Committing Transaction.");
txn.Commit();
Console.WriteLine("Inserted " + rows + " rows. ");
}
_conn.Close();
}
}
}
4.3.3 - Streaming data via ADO.NET
There are two options to stream data from a file on the client to your Vertica database through ADO.NET:.
There are two options to stream data from a file on the client to your Vertica database through ADO.NET:
The topics in this section explain how to use these options.
4.3.3.1 - Streaming from the client via VerticaCopyStream
The VerticaCopyStream class lets you stream data from the client system to a Vertica database.
The VerticaCopyStream
class lets you stream data from the client system to a Vertica database. It lets you use the SQL COPY statement directly without having to copy the data to a host in the database cluster first by substituting one or more data stream(s) for STDIN.
Notes:
-
Use Transactions and disable auto commit on the copy command for better performance.
-
Disable auto commit using the copy command with the 'no commit' modifier. You must explicitly disable commits. Enabling transactions does not disable autocommit when using VerticaCopyStream.
-
The copy command used with VerticaCopyStream uses copy syntax.
-
VerticaCopyStream.rejects is zeroed every time execute is called. If you want to capture the number of rejects, assign the value of VerticaCopyStream.rejects to another variable before calling execute again.
-
You can add multiple streams using multiple AddStream() calls.
Example usage:
The following example demonstrates using VerticaCopyStream to copy a file stream into Vertica.
using System;
using System.Collections.Generic;
using System.Linq;
using System.Text;
using System.Data;
using System.IO;
using Vertica.Data.VerticaClient;
namespace ConsoleApplication
{
class Program
{
static void Main(string[] args)
{
// Configure connection properties
VerticaConnectionStringBuilder builder = new VerticaConnectionStringBuilder();
builder.Host = "192.168.1.10";
builder.Database = "VMart";
builder.User = "dbadmin";
//open the connection
VerticaConnection _conn = new VerticaConnection(builder.ToString());
_conn.Open();
try
{
using (_conn)
{
// Start a transaction
VerticaTransaction txn = _conn.BeginTransaction();
// Create a table for this example
VerticaCommand command = new VerticaCommand("DROP TABLE IF EXISTS copy_table", _conn);
command.ExecuteNonQuery();
command.CommandText = "CREATE TABLE copy_table (Last_Name char(50), "
+ "First_Name char(50),Email char(50), "
+ "Phone_Number char(15))";
command.ExecuteNonQuery();
// Create a new filestream from the data file
string filename = "C:/customers.txt";
Console.WriteLine("\n\nLoading File: " + filename);
FileStream inputfile = File.OpenRead(filename);
// Define the copy command
string copy = "copy copy_table from stdin record terminator E'\n' delimiter '|'" + " enforcelength "
+ " no commit";
// Create a new copy stream instance with the connection and copy statement
VerticaCopyStream vcs = new VerticaCopyStream(_conn, copy);
// Start the VerticaCopyStream process
vcs.Start();
// Add the file stream
vcs.AddStream(inputfile, false);
// Execute the copy
vcs.Execute();
// Finish stream and write out the list of inserted and rejected rows
long rowsInserted = vcs.Finish();
IList<long> rowsRejected = vcs.Rejects;
// Does not work when rejected or exceptions defined
Console.WriteLine("Number of Rows inserted: " + rowsInserted);
Console.WriteLine("Number of Rows rejected: " + rowsRejected.Count);
if (rowsRejected.Count > 0)
{
for (int i = 0; i < rowsRejected.Count; i++)
{
Console.WriteLine("Rejected row #{0} is row {1}", i, rowsRejected[i]);
}
}
// Commit the changes
txn.Commit();
}
}
catch (Exception e)
{
Console.WriteLine(e.Message);
}
//close the connection
_conn.Close();
}
}
}
4.3.3.2 - Using copy with ADO.NET
To use COPY with ADO.NET, just execute a COPY statement and the path to the source file on the client system.
To use COPY with ADO.NET, just execute a COPY statement and the path to the source file on the client system. This method is simpler than using the VerticaCopyStream class. However, you may prefer using VerticaCopyStream if you have many files to copy to the database or if your data comes from a source other than a local file (streamed over a network connection, for example).
The following example code demonstrates using COPY to copy a file from the client to the database. It is the same as the code shown in Bulk Loading Using the COPY Statement and the path to the data file is on the client system, rather than on the server.
To load data that is stored on a database node, use a VerticaCommand object to create a COPY command:
-
Create a connection to the database through the node on which the data file is stored.
-
Create a command object using the connection.
VerticaCommand command = _conn.CreateCommand();
-
Copy data. The following is an example of using the COPY command to load data. It uses the LOCAL modifier to copy a file local to the client issuing the command.
command.CommandText = "copy lcopy_table from '/home/dbadmin/customers.txt'"
+ " record terminator E'\n' delimiter '|'"
+ " enforcelength ";
Int32 insertedRows = command.ExecuteNonQuery();
Console.WriteLine(insertedRows + " inserted.");
Example usage:
using System;
using System.Collections.Generic;
using System.Linq;
using System.Text;
using System.Data;
using System.IO;
using Vertica.Data.VerticaClient;
namespace ConsoleApplication
{
class Program
{
static void Main(string[] args)
{
// Configure connection properties
VerticaConnectionStringBuilder builder = new VerticaConnectionStringBuilder();
builder.Host = "192.168.1.10";
builder.Database = "VMart";
builder.User = "dbadmin";
// Open the connection
VerticaConnection _conn = new VerticaConnection(builder.ToString());
_conn.Open();
try
{
using (_conn)
{
// Start a transaction
VerticaTransaction txn = _conn.BeginTransaction();
// Create a table for this example
VerticaCommand command = new VerticaCommand("DROP TABLE IF EXISTS lcopy_table", _conn);
command.ExecuteNonQuery();
command.CommandText = "CREATE TABLE IF NOT EXISTS lcopy_table (Last_Name char(50), "
+ "First_Name char(50),Email char(50), "
+ "Phone_Number char(15))";
command.ExecuteNonQuery();
// Define the copy command
command.CommandText = "copy lcopy_table from '/home/dbadmin/customers.txt'"
+ " record terminator E'\n' delimiter '|'"
+ " enforcelength "
+ " no commit";
// Execute the copy
Int32 insertedRows = command.ExecuteNonQuery();
Console.WriteLine(insertedRows + " inserted.");
// Commit the changes
txn.Commit();
}
}
catch (Exception e)
{
Console.WriteLine("Exception: " + e.Message);
}
// Close the connection
_conn.Close();
}
}
}
5 - Canceling ADO.NET queries
You can cancel a running vsql query by calling the .Cancel() method of any Command object.
You can cancel a running vsql query by calling the .Cancel()
method of any Command object. The SampleCancelTests
class demonstrates how to cancel a query after reading a specified number of rows. It implements the following methods:
SampleCancelTest()
executes the Setup()
function to create a test table. Then, it calls RunQueryAndCancel()
and RunSecondQuery()
to demonstrate how to cancel a query after it reads a specified number of rows. Finally, it runs the Cleanup()
function to drop the test table.
Setup()
creates a database for the example queries.
Cleanup()
drops the database.
RunQueryAndCancel()
reads exactly 100 rows from a query that returns more than 100 rows.
RunSecondQuery()
reads all rows from a query.
using System;
using Vertica.Data.VerticaClient;
class SampleCancelTests
{
// Creates a database table, executes a query that cancels during a read loop,
// executes a query that does not cancel, then drops the test database table.
// connection: A connection to a Vertica database.
public static void SampleCancelTest(VerticaConnection connection)
{
VerticaCommand command = connection.CreateCommand();
Setup(command);
try
{
Console.WriteLine("Running query that will cancel after reading 100 rows...");
RunQueryAndCancel(command);
Console.WriteLine("Running a second query...");
RunSecondQuery(command);
Console.WriteLine("Finished!");
}
finally
{
Cleanup(command);
}
}
// Set up the database table for the example.
// command: A Command object used to execute the query.
private static void Setup(VerticaCommand command)
{
// Create table used for test.
Console.WriteLine("Creating and loading table...");
command.CommandText = "DROP TABLE IF EXISTS adocanceltest";
command.ExecuteNonQuery();
command.CommandText = "CREATE TABLE adocanceltest(id INTEGER, time TIMESTAMP)";
command.ExecuteNonQuery();
command.CommandText = @"INSERT INTO adocanceltest
SELECT row_number() OVER(), slice_time
FROM(
SELECT slice_time FROM(
SELECT '2021-01-01'::timestamp s UNION ALL SELECT '2022-01-01'::timestamp s
) sq TIMESERIES slice_time AS '1 second' OVER(ORDER BY s)
) sq2";
command.ExecuteNonQuery();
}
// Clean up the database after running the example.
// command: A Command object used to execute the query.
private static void Cleanup(VerticaCommand command)
{
command.CommandText = "DROP TABLE IF EXISTS adocanceltest";
command.ExecuteNonQuery();
}
// Execute a query that returns many rows and cancels after reading 100.
// command: A Command object used to execute the query.
private static void RunQueryAndCancel(VerticaCommand command)
{
command.CommandText = "SELECT COUNT(id) from adocanceltest";
int fullRowCount = Convert.ToInt32(command.ExecuteScalar());
command.CommandText = "SELECT id, time FROM adocanceltest";
VerticaDataReader dr = command.ExecuteReader();
int nCount = 0;
try
{
while (dr.Read())
{
nCount++;
if (nCount == 100)
{
// After reaching 100 rows, cancel the command
// Note that it is not necessary to read the remaining rows
command.Cancel();
return;
}
}
}
catch (Exception e)
{
Console.WriteLine(e.Message);
}
finally
{
dr.Close();
// Verify that the cancel stopped the query
Console.WriteLine((fullRowCount - nCount) + " rows out of " + fullRowCount + " discarded by cancel");
}
}
// Execute a simple query and read all results.
// command: A Command object used to execute the query.
private static void RunSecondQuery(VerticaCommand command)
{
command.CommandText = "SELECT 1 FROM dual";
VerticaDataReader dr = command.ExecuteReader();
try
{
while (dr.Read())
{
;
}
}
catch (Exception e)
{
Console.WriteLine(e.Message);
Console.WriteLine("Warning: no exception should be thrown on query after cancel");
}
finally
{
dr.Close();
}
}
}
6 - Handling messages (ADO.NET)
You can capture info and warning messages that Vertica provides to the ADO.NET driver by using the InfoMessage event on the VerticaConnection delegate class.
You can capture info and warning messages that Vertica provides to the ADO.NET driver by using the InfoMessage event on the VerticaConnection delegate class. This class captures messages that are not severe enough to force an exception to be triggered, but might still provide information that can benefit your application.
To use the VerticaInfoMessageEventHander class:
-
Create a method to handle the message sent from the even handler:
static void conn_InfoMessage(object sender, VerticaInfoMessageEventArgs e)
{
Console.WriteLine(e.SqlState + ": " + e.Message);
}
-
Create a connection and register a new VerticaInfoMessageHandler delegate for the InfoMessage event:
_conn.InfoMessage += new VerticaInfoMessageEventHandler(conn_InfoMessage);
-
Execute your queries. If a message is generated, then the event handle function is run.
-
You can unsubscribe from the event with the following command:
_conn.InfoMessage -= new VerticaInfoMessageEventHandler(conn_InfoMessage);
Example usage:
using System;
using System.Collections.Generic;
using System.Linq;
using System.Text;
using System.Data;
using Vertica.Data.VerticaClient;
namespace ConsoleApplication
{
class Program
{
// define message handler to deal with messages
static void conn_InfoMessage(object sender, VerticaInfoMessageEventArgs e)
{
Console.WriteLine(e.SqlState + ": " + e.Message);
}
static void Main(string[] args)
{
//configure connection properties
VerticaConnectionStringBuilder builder = new VerticaConnectionStringBuilder();
builder.Host = "192.168.1.10";
builder.Database = "VMart";
builder.User = "dbadmin";
//open the connection
VerticaConnection _conn = new VerticaConnection(builder.ToString());
_conn.Open();
//create message handler instance by subscribing it to the InfoMessage event of the connection
_conn.InfoMessage += new VerticaInfoMessageEventHandler(conn_InfoMessage);
//create and execute the command
VerticaCommand cmd = _conn.CreateCommand();
cmd.CommandText = "drop table if exists fakeTable";
cmd.ExecuteNonQuery();
//close the connection
_conn.Close();
}
}
}
This examples displays the following when run:
00000: Nothing was dropped
7 - Getting table metadata (ADO.Net)
You can get the table metadata by using the GetSchema() method on a connection and loading the metadata into a DataTable:.
You can get the table metadata by using the GetSchema() method on a connection and loading the metadata into a DataTable:
-
database_name
, schema_name
, and table_name
can be set to null
, a specific name, or use a LIKE pattern.
-
table_type
can be one of:
-
"SYSTEM TABLE"
-
"TABLE"
-
"GLOBAL TEMPORARY"
-
"LOCAL TEMPORARY"
-
"VIEW"
-
null
-
If table_type
is null
, then the metadata for all metadata tables is returned.
For example:
DataTable table = _conn.GetSchema("Tables", new string[] { null, null, null, "SYSTEM TABLE" });
Examples
using System;
using System.Collections.Generic;
using System.Linq;
using System.Text;
using System.Data;
using Vertica.Data.VerticaClient;
namespace ConsoleApplication
{
class Program
{
static void Main(string[] args)
{
// configure connection properties
VerticaConnectionStringBuilder builder = new VerticaConnectionStringBuilder();
builder.Host = "192.168.1.10";
builder.Database = "VMart";
builder.User = "dbadmin";
// open the connection
VerticaConnection _conn = new VerticaConnection(builder.ToString());
_conn.Open();
// create a new data table containing the schema
// the last argument can be "SYSTEM TABLE", "TABLE", "GLOBAL TEMPORARY",
// "LOCAL TEMPORARY", "VIEW", or null for all types
DataTable table = _conn.GetSchema("Tables", new string[] { null, null, null, "SYSTEM TABLE" });
// print out the schema
foreach (DataRow row in table.Rows) {
foreach (DataColumn col in table.Columns)
{
Console.WriteLine("{0} = {1}", col.ColumnName, row[col]);
}
Console.WriteLine("============================");
}
//close the connection
_conn.Close();
}
}
}