|
| 1 | +# Basic Usage with ADO.NET |
| 2 | + |
| 3 | +This article covers core [ADO.NET](https://learn.microsoft.com/en-us/dotnet/framework/data/adonet/) usage scenarios for {{ ydb-short-name }}, including database connections, query execution, and result processing. See the main [documentation](index.md) for additional details. |
| 4 | + |
| 5 | +## Connections |
| 6 | + |
| 7 | +A connection to {{ ydb-short-name }} is established using `YdbConnection`. |
| 8 | + |
| 9 | +1. **Using an empty connection**: |
| 10 | + |
| 11 | + The following code creates a connection with the default settings: |
| 12 | + |
| 13 | + ```c# |
| 14 | + await using var ydbConnection = new YdbConnection(""); |
| 15 | + await ydbConnection.OpenAsync(); |
| 16 | + ``` |
| 17 | + |
| 18 | + This option creates a connection to the database at the URL `grpc://localhost:2136/local` with anonymous authentication. |
| 19 | +
|
| 20 | +2. **Using the constructor with a connection string**: |
| 21 | + |
| 22 | + In the following example, a connection is created using a [connection string in ADO.NET](https://learn.microsoft.com/en-us/dotnet/framework/data/adonet/connection-strings): |
| 23 | +
|
| 24 | + ```c# |
| 25 | + await using var ydbConnection = new YdbConnection( |
| 26 | + "Host=database-sample-grpc;Port=2135;Database=/root/database-sample"); |
| 27 | + await ydbConnection.OpenAsync(); |
| 28 | + ``` |
| 29 | + |
| 30 | + In this case, the connection is established at the URL `grpc://database-sample-grpc:2135/root/database-sample`. The supported set of settings is explained on the [connection parameters page](connection-parameters.md). |
| 31 | +
|
| 32 | +3. **Using the constructor with a `YdbConnectionStringBuilder` argument**: |
| 33 | + |
| 34 | + The example using `YdbConnectionStringBuilder` is demonstrated in the code below: |
| 35 | + |
| 36 | + ```c# |
| 37 | + var ydbConnectionBuilder = new YdbConnectionStringBuilder |
| 38 | + { |
| 39 | + Host = "server", |
| 40 | + Port = 2135, |
| 41 | + Database = "/ru-prestable/my-table", |
| 42 | + UseTls = true |
| 43 | + }; |
| 44 | + await using var ydbConnection = new YdbConnection(ydbConnectionBuilder); |
| 45 | + await ydbConnection.OpenAsync(); |
| 46 | + ``` |
| 47 | + |
| 48 | + `YdbConnectionStringBuilder` supports additional [configuration](connection-parameters.md#connection-builder-parameters) beyond the connection string, such as logging, advanced authentication options. |
| 49 | + |
| 50 | +## Pooling |
| 51 | + |
| 52 | +Opening and closing a logical connection to {{ ydb-short-name }} is an expensive and time-consuming process. Therefore, connections to {{ ydb-short-name }} are pooled. Closing or disposing of a connection does not close the underlying logical connection; rather, it returns it to a pool managed by `Ydb.Sdk.Ado`. When a connection is needed again, a pooled connection is returned. This makes opening and closing operations extremely fast. Do not hesitate to open and close connections often if necessary, rather than keeping a connection open unnecessarily for a long period of time. |
| 53 | + |
| 54 | +#### ClearPool |
| 55 | + |
| 56 | +Closes idle connections immediately. Active connections close when returned. |
| 57 | + |
| 58 | +```c# |
| 59 | +YdbConnection.ClearPool(ydbConnection) |
| 60 | +``` |
| 61 | + |
| 62 | +#### ClearAllPools |
| 63 | + |
| 64 | +Closes all idle connections across all pools. Active connections close on return. |
| 65 | + |
| 66 | +```c# |
| 67 | +YdbConnection.ClearAllPools() |
| 68 | +``` |
| 69 | + |
| 70 | +## Data Source |
| 71 | + |
| 72 | +Starting with .NET 7.0, the starting point for any database operation is [DbDataSource](https://learn.microsoft.com/en-us/dotnet/api/system.data.common.dbdatasource). |
| 73 | +
|
| 74 | +The simplest way to create a data source is the following: |
| 75 | + |
| 76 | +```c# |
| 77 | +await using var dataSource = new YdbDataSource("Host=localhost;Port=2136;Database=/local"); |
| 78 | +``` |
| 79 | + |
| 80 | +Or |
| 81 | + |
| 82 | +```c# |
| 83 | +var ydbConnectionBuilder = new YdbConnectionStringBuilder |
| 84 | +{ |
| 85 | + Host = "localhost", |
| 86 | + Port = 2136, |
| 87 | + Database = "/local", |
| 88 | + UseTls = false |
| 89 | +}; |
| 90 | + |
| 91 | +await using var dataSource = new YdbDataSource(ydbConnectionBuilder); |
| 92 | +``` |
| 93 | + |
| 94 | +## Basic SQL Execution |
| 95 | + |
| 96 | +Once you have a `YdbConnection`, an `YdbCommand` can be used to execute SQL against it: |
| 97 | + |
| 98 | +```c# |
| 99 | +await using var command = dataSource.CreateCommand("SELECT some_field FROM some_table") |
| 100 | +await using var reader = await command.ExecuteReaderAsync(); |
| 101 | + |
| 102 | +while (await reader.ReadAsync()) |
| 103 | +{ |
| 104 | + Console.WriteLine(reader.GetString(0)); |
| 105 | +} |
| 106 | +``` |
| 107 | + |
| 108 | +## Other Execution Methods |
| 109 | + |
| 110 | +Above, SQL is executed via [ExecuteReaderAsync](https://learn.microsoft.com/en-us/dotnet/api/system.data.common.dbcommand.executereaderasync). There are various ways to execute a command, depending on the results you expect from it: |
| 111 | +
|
| 112 | +1. [ExecuteNonQueryAsync](https://learn.microsoft.com/en-us/dotnet/api/system.data.common.dbcommand.executenonqueryasync): executes SQL that doesn't return any results, typically `INSERT`, `UPDATE`, or `DELETE` statements. |
| 113 | +
|
| 114 | + {% note warning %} |
| 115 | + |
| 116 | + {{ ydb-short-name }} does not return the number of rows affected. |
| 117 | + |
| 118 | + {% endnote %} |
| 119 | + |
| 120 | +2. [ExecuteScalarAsync](https://learn.microsoft.com/en-us/dotnet/api/system.data.common.dbcommand.executescalarasync): executes SQL that returns a single scalar value. |
| 121 | +3. [ExecuteReaderAsync](https://learn.microsoft.com/en-us/dotnet/api/system.data.common.dbcommand.executereaderasync): executes SQL that returns a full result set. Returns a `YdbDataReader`, which can be used to access the result set (as in the example above). |
| 122 | +
|
| 123 | +For example, to execute a simple SQL `INSERT` that does not return anything, you can use `ExecuteNonQueryAsync` as follows: |
| 124 | + |
| 125 | +```c# |
| 126 | +await using var command = dataSource.CreateCommand("INSERT INTO some_table (some_field) VALUES ('Hello YDB!'u)"); |
| 127 | +await command.ExecuteNonQueryAsync(); |
| 128 | +``` |
| 129 | + |
| 130 | +## Parameters |
| 131 | + |
| 132 | +When sending data values to the database, always consider using parameters rather than including the values in the SQL, as shown in the following example: |
| 133 | + |
| 134 | +```c# |
| 135 | +await using var connection = new YdbConnection(_cmdOptions.SimpleConnectionString); |
| 136 | +await connection.OpenAsync(); |
| 137 | + |
| 138 | +var ydbCommand = connection.CreateCommand(); |
| 139 | +ydbCommand.CommandText = """ |
| 140 | + DECLARE $series_id AS Uint64; |
| 141 | + DECLARE $season_id AS Uint64; |
| 142 | + DECLARE $limit_size AS Uint64; |
| 143 | + |
| 144 | + SELECT series_id, season_id, episode_id, air_date, title |
| 145 | + FROM episodes WHERE series_id = $series_id AND season_id > $season_id |
| 146 | + ORDER BY series_id, season_id, episode_id |
| 147 | + LIMIT $limit_size; |
| 148 | + """; |
| 149 | +ydbCommand.Parameters.Add(new YdbParameter("$series_id", DbType.UInt64, 1U)); |
| 150 | +ydbCommand.Parameters.Add(new YdbParameter("$season_id", DbType.UInt64, 1U)); |
| 151 | +ydbCommand.Parameters.Add(new YdbParameter("$limit_size", DbType.UInt64, 3U)); |
| 152 | + |
| 153 | +var ydbDataReader = await ydbCommand.ExecuteReaderAsync(); |
| 154 | +``` |
| 155 | + |
| 156 | +SQL query parameters can be set using the `YdbParameter` class. |
| 157 | + |
| 158 | +In this example, the parameters `$series_id`, `$season_id`, and `$limit_size` are declared within the SQL query and then added to the command using `YdbParameter` objects. |
| 159 | + |
| 160 | +## Alternative Parameter Style with `@` Prefix |
| 161 | + |
| 162 | +Parameters can also be specified using the `@` prefix. In this case, there is no need to declare variables within the query itself. The query will look like this: |
| 163 | + |
| 164 | +```c# |
| 165 | +ydbCommand.CommandText = """ |
| 166 | + SELECT series_id, season_id, episode_id, air_date, title |
| 167 | + FROM episodes |
| 168 | + WHERE series_id = @series_id AND season_id > @season_id |
| 169 | + ORDER BY series_id, season_id, episode_id |
| 170 | + LIMIT @limit_size; |
| 171 | + """; |
| 172 | +ydbCommand.Parameters.Add(new YdbParameter("series_id", DbType.UInt64, 1U)); |
| 173 | +ydbCommand.Parameters.Add(new YdbParameter("season_id", DbType.UInt64, 1U)); |
| 174 | +ydbCommand.Parameters.Add(new YdbParameter("limit_size", DbType.UInt64, 3U)); |
| 175 | +``` |
| 176 | + |
| 177 | +With ADO.NET, the query will be prepared for you so that the variables match [YQL](../../yql/reference/index.md). The type will be determined according to the [DbType](https://learn.microsoft.com/en-us/dotnet/api/system.data.dbtype) or the .NET type of the value itself. |
| 178 | +
|
| 179 | +## Parameter Types |
| 180 | + |
| 181 | +{{ ydb-short-name }} has a strongly-typed type system: columns and parameters have a type, and types are usually not implicitly converted to other types. This means you have to think about which type you will be sending: trying to insert a string into an integer column (or vice versa) will fail. |
| 182 | + |
| 183 | +For more information on supported types and their mappings, see this [page](type-mapping.md). |
| 184 | + |
| 185 | +## Transactions |
| 186 | + |
| 187 | +To create a client transaction, use the standard ADO.NET `ydbConnection.BeginTransaction()` method. |
| 188 | + |
| 189 | +There are two signatures of this method with a single isolation level parameter: |
| 190 | + |
| 191 | +- `BeginTransaction(TxMode txMode)`<br> |
| 192 | + The `Ydb.Sdk.Services.Query.TxMode` is a {{ ydb-short-name }} specific isolation level, you can read more about it [here](../../../concepts/transactions.md). |
| 193 | + |
| 194 | +- `BeginTransaction(IsolationLevel isolationLevel)`<br> |
| 195 | + The `System.Data.IsolationLevel` parameter from the standard ADO.NET. The following isolation levels are supported: `Serializable` and `Unspecified`. Both are equivalent to the `TxMode.SerializableRW`. |
| 196 | + |
| 197 | +Calling `BeginTransaction()` without parameters opens a transaction with level the `TxMode.SerializableRW`. |
| 198 | + |
| 199 | +Consider the following example of using a transaction: |
| 200 | + |
| 201 | +```c# |
| 202 | +await using var connection = await dataSource.OpenConnectionAsync(); |
| 203 | +await using var transaction = await connection.BeginTransactionAsync(); |
| 204 | + |
| 205 | +await using var command1 = new YdbCommand(connection) { CommandText = "...", Transaction = transaction }; |
| 206 | +await command1.ExecuteNonQueryAsync(); |
| 207 | + |
| 208 | +await using var command2 = new YdbCommand(connection) { CommandText = "...", Transaction = transaction }; |
| 209 | +await command2.ExecuteNonQueryAsync(); |
| 210 | + |
| 211 | +await transaction.CommitAsync(); |
| 212 | +``` |
| 213 | + |
| 214 | +{{ ydb-short-name }} does not support nested or concurrent transactions. At any given moment, only one transaction per connection can be in progress, and starting a new transaction while another is already running throws an exception. Therefore, there is no need to pass the `YdbTransaction` object returned by `BeginTransaction()` to commands you execute. When a transaction is started, all subsequent commands are automatically included until a commit or rollback is made. To ensure maximum portability, however, it is best to set the transaction scope for your commands explicitly. |
| 215 | + |
| 216 | +## Error Handling |
| 217 | + |
| 218 | +All exceptions related to database operations are subclasses of `YdbException`. |
| 219 | + |
| 220 | +To safely handle errors that might occur during command execution, you can use a `try-catch` block. Here is an example: |
| 221 | + |
| 222 | +```c# |
| 223 | +try |
| 224 | +{ |
| 225 | + await command.ExecuteNonQueryAsync(); |
| 226 | +} |
| 227 | +catch (YdbException e) |
| 228 | +{ |
| 229 | + Console.WriteLine($"Error executing command: {e}"); |
| 230 | +} |
| 231 | +``` |
| 232 | + |
| 233 | +### Properties of `YdbException` |
| 234 | + |
| 235 | +The `YdbException` exception has the following properties, which can help you handle errors properly: |
| 236 | + |
| 237 | +- `IsTransient` returns `true` if the error is temporary and can be resolved by retrying. For example, this might occur in cases of a transaction lock violation when the transaction fails to complete its commit. |
| 238 | + |
| 239 | +- `IsTransientWhenIdempotent` returns `true` if the error is temporary and can be resolved by retrying the operation, provided that the database operation is idempotent. |
| 240 | + |
| 241 | +- `StatusCode` contains the database error code, which is helpful for logging and detailed analysis of the issue. |
| 242 | + |
| 243 | +{% note warning %} |
| 244 | + |
| 245 | +Please note that ADO.NET does not automatically retry failed operations, and you must implement retry logic in your code. |
| 246 | + |
| 247 | +{% endnote %} |
| 248 | + |
| 249 | +## Examples |
| 250 | + |
| 251 | +Examples are provided on GitHub at [link](https://github.com/ydb-platform/ydb-dotnet-sdk/tree/main/examples/src/AdoNet). |
0 commit comments