Skip to content
Open
1 change: 1 addition & 0 deletions .gitignore
Original file line number Diff line number Diff line change
Expand Up @@ -405,3 +405,4 @@ FodyWeavers.xsd
/DotNet/SqlServer.NativeVectorSearch.Samples/Properties/launchSettingsProd.json
/DotNet/SqlClient/Properties/launchSettings Empty.json
/DotNet/SqlClient/Properties/launchSettingsProd.json
/DotNet/SqlClient/Properties/launchSettings.prod.json
115 changes: 76 additions & 39 deletions DotNet/SqlClient/Program.cs
Original file line number Diff line number Diff line change
@@ -1,9 +1,12 @@
using System.Diagnostics;
using System.Globalization;
using System.Text.Json;
using System.Text;
using Microsoft.Data;
using Microsoft.Data.SqlClient;
using Microsoft.Data.SqlTypes;
using OpenAI.Embeddings;
using System.Data;
using System.Diagnostics;
using System.Globalization;
using System.Text;
using System.Text.Json;

namespace SqlServer.NativeVectorSearch.Samples
{
Expand All @@ -24,6 +27,7 @@ internal class Program
private static string _cConnStr;
private static string _cEmbeddingModel;
private static string _cApiKey;
private static string _cTableName = "Vectors2";

static Program()
{
Expand All @@ -37,11 +41,15 @@ static async Task Main(string[] args)
{
Console.WriteLine("Hello, World!");

//await CreateAndInsertVectorsAsync();
//await CreateAndInsertEmbeddingAsync();
//await ReadVectorsAsync();
// await FindSimilarAsync();
//await GenerateTestDocumentsAsync();
await CreateAndInsertVectorsAsync();

await CreateAndInsertEmbeddingAsync();

await ReadVectorsAsync();

await FindSimilarAsync();

await GenerateTestDocumentsAsync();

await ClassifyDocumentsAsync();

Expand All @@ -58,30 +66,34 @@ public static async Task CreateAndInsertVectorsAsync()
using (SqlConnection connection = new SqlConnection(_cConnStr))
{
// Vector is inserted in the column '[VectorShort] VECTOR(3) NULL'
string sql = $"INSERT INTO [test].[Vectors] ([VectorShort]) VALUES (@Vector)";
string sql = $"INSERT INTO [test].[{_cTableName}] ([VectorShort]) VALUES (@Vector)";

SqlCommand command1 = new SqlCommand(sql, connection);
SqlCommand command = new SqlCommand(sql, connection);

// Insert vector as string. Note JSON array.
command1.Parameters.AddWithValue("@Vector", "[1.12, 2.22, 3.33]");
// Demonstrates how to use the new SqlVector<T> type to insert the vector.
command.Parameters.AddWithValue("@Vector", new SqlVector<float>(new float[] { 7.01f, 7.02f, -7.03f }));

SqlCommand command2 = new SqlCommand(sql, connection);
// Alternative way how to add the vector parameter.
//var prm = command.Parameters.Add("@Vector", SqlDbTypeExtensions.Vector);
//prm.Value= new SqlVector<float>( new float[] { 7.01f, 7.02f, -7.03f });

// OBSOLETE:
// Supported for compatibility with the old driver Microsoft.Data.SqlClient: Version < 6.1.0.
// Insert vector as string. Note JSON array.
// command.Parameters.AddWithValue("@Vector", "[7.12, -2.22, 3.33]");
// Insert vector as JSON string serialized from the float array.
command2.Parameters.AddWithValue("@Vector", JsonSerializer.Serialize(new float[] { 1.12f, 2.22f, 3.33f }));
// command.Parameters.AddWithValue("@Vector", JsonSerializer.Serialize(new float[] { 4.12f, 22.22f, -3.33f }));

connection.Open();

var result1 = await command1.ExecuteNonQueryAsync();

var result2 = await command2.ExecuteNonQueryAsync();
var result = await command.ExecuteNonQueryAsync();

connection.Close();
}
}

/// <summary>
/// Demonstrates how to create a embedding vector from a string by using the embedding model and how to insert it into the table.
/// Demonstrates how to create a embedding vector and how to insert it into the table.
/// </summary>
/// <returns></returns>
public static async Task CreateAndInsertEmbeddingAsync()
Expand All @@ -91,7 +103,7 @@ public static async Task CreateAndInsertEmbeddingAsync()
// The text to be converted to a vector.
string text = "Native Vector Search for SQL Server";

// Generate the embedding vector.
// Generate the embedding vector by using OpenAI SDK
var res = await client.GenerateEmbeddingsAsync(new List<string>() { text });

OpenAIEmbedding embedding = res.Value.First();
Expand All @@ -106,9 +118,15 @@ public static async Task CreateAndInsertEmbeddingAsync()
var id = Guid.NewGuid().ToString();

// Embedding is inserted in the column '[Vector] VECTOR(1536) NULL'
SqlCommand command = new SqlCommand($"INSERT INTO [test].[Vectors] ([Vector], [Text]) VALUES ( @Vector, @Text)", connection);
SqlCommand command = new SqlCommand($"INSERT INTO [test].[{_cTableName}] ([Vector], [Text]) VALUES ( @Vector, @Text)", connection);

// Demonstrates how to use the new SqlVector<T> type to insert the vector.
command.Parameters.AddWithValue("@Vector", new SqlVector<float>(embeddingVector.ToArray()));

//
// OBSOLETE: Supported for compatibility with the old driver Microsoft.Data.SqlClient: Version < 6.1.0.
//command.Parameters.AddWithValue("@Vector", JsonSerializer.Serialize(embeddingVector.ToArray()));

command.Parameters.AddWithValue("@Vector", JsonSerializer.Serialize(embeddingVector.ToArray()));
command.Parameters.AddWithValue("@Text", text);

connection.Open();
Expand All @@ -132,11 +150,11 @@ public static async Task GenerateRandomVectorsAsync(int howMany = 10000)

for (int i = 0; i < howMany; i++)
{
string sql = $"INSERT INTO [test].[Vectors] ([Vector],[Text]) VALUES (@Vector, @Text)";
string sql = $"INSERT INTO [test].[{_cTableName}] ([Vector],[Text]) VALUES (@Vector, @Text)";

SqlCommand command1 = new SqlCommand(sql, connection);

command1.Parameters.AddWithValue("@Vector", JsonSerializer.Serialize(CreateRandomVector()));
command1.Parameters.AddWithValue("@Vector", new SqlVector<float>(CreateRandomVector()));
command1.Parameters.AddWithValue("@Text", i.ToString("D4"));

var result1 = await command1.ExecuteNonQueryAsync();
Expand All @@ -146,9 +164,11 @@ public static async Task GenerateRandomVectorsAsync(int howMany = 10000)
}
}


/// <summary>
/// Demonstrates how to read vectors from the table.
/// Please nite the code is not optimized. It is for demonstration purposes only to understand
/// how to deal with the vector type.
/// </summary>
/// <returns></returns>

Expand All @@ -160,18 +180,36 @@ public static async Task ReadVectorsAsync()
{
var id = Guid.NewGuid().ToString();

SqlCommand command = new SqlCommand($"Select TOP(100) * FROM [test].[Vectors]", connection);
SqlCommand command = new SqlCommand($"Select TOP(100) * FROM [test].[{_cTableName}]", connection);

connection.Open();

using (SqlDataReader reader = await command.ExecuteReaderAsync())
{
while (await reader.ReadAsync())
{
//
// Demonstrates how to read the vector as a native type.
var vectorShort = reader.IsDBNull(reader.GetOrdinal("VectorShort")) ?
SqlVector<float>.CreateNull(3) :
reader.GetSqlVector<float>(reader.GetOrdinal("VectorShort"));

var vectorEmbedding = reader.IsDBNull(reader.GetOrdinal("Vector")) ?
SqlVector<float>.CreateNull(1536) :
reader.GetSqlVector<float>(reader.GetOrdinal("Vector"));

//
// Demonstrates ow to get a float array from the vector type.
float[] arrShort = vectorShort.Memory.ToArray();
float[] arrEmbedding = vectorEmbedding.Memory.ToArray();

(long Id, string VectorShort, string Vector, string Text) row = new(
reader.GetInt32(reader.GetOrdinal("Id")),
reader.IsDBNull(reader.GetOrdinal("VectorShort")) ? "-" : reader.GetString(reader.GetOrdinal("VectorShort")),
reader.IsDBNull(reader.GetOrdinal("Vector")) ? "-" : reader.GetString(reader.GetOrdinal("Vector")).Substring(0, 20) + "...",
string.Join(", ", arrShort),
string.Join(", ", arrEmbedding).Substring(0, Math.Min(75, arrEmbedding.Length)) + " ... ",
// OBSOLETE: Supported for compatibility with the old driver Microsoft.Data.SqlClient: Version < 6.1.0.
//reader.IsDBNull(reader.GetOrdinal("VectorShort")) ? "-" : reader.GetString(reader.GetOrdinal("VectorShort")),
//reader.IsDBNull(reader.GetOrdinal("Vector")) ? "-" : reader.GetString(reader.GetOrdinal("Vector")).Substring(0, 20) + "...",
reader.IsDBNull(reader.GetOrdinal("Text")) ? "-" : reader.GetString(reader.GetOrdinal("Text"))
);

Expand All @@ -184,7 +222,7 @@ public static async Task ReadVectorsAsync()

foreach (var row in rows)
{
Console.WriteLine($"{row.Id}, {row.Vector}, {row.Text}");
Console.WriteLine($"{row.Id}, {row.VectorShort}, {row.Vector}, {row.Text}");
}
}

Expand All @@ -204,9 +242,9 @@ public static async Task FindSimilarAsync()
{
var id = Guid.NewGuid().ToString();

SqlCommand command = new SqlCommand($"Select TOP(100) Id, Text, VECTOR_DISTANCE('cosine', CAST(@Embedding AS Vector(3)), VectorShort) AS Distance FROM [test].[Vectors]", connection);
SqlCommand command = new SqlCommand($"Select TOP(100) Id, Text, VECTOR_DISTANCE('cosine', CAST(@Embedding AS Vector(3)), VectorShort) AS Distance FROM [test].[{_cTableName}]", connection);
Copy link
Collaborator

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

I think that CAST(@Embedding AS Vector(3)) can be removed as @Embedding is already a vector now


command.Parameters.AddWithValue("@Embedding", JsonSerializer.Serialize(embedding));
command.Parameters.AddWithValue("@Embedding", new SqlVector<float>(embedding));

connection.Open();

Expand Down Expand Up @@ -282,7 +320,7 @@ public static async Task FindSimilarAsync()
/// </summary>
/// <returns></returns>
public static async Task ClassifyDocumentsAsync()
{
{
var invoicesEng = await GetMatching(20, "invoice total item");

var invoiceGER = await GetMatching(20, "rechnung item gesammt");
Expand Down Expand Up @@ -354,9 +392,9 @@ public static async Task ClassificationByDocumentCountry_Test()
{
var id = Guid.NewGuid().ToString();

SqlCommand command = new SqlCommand($"Select TOP({howMany}) Id, Text, VECTOR_DISTANCE('cosine', CAST(@Embedding AS Vector(1536)), Vector) AS Distance FROM [test].[Vectors] ORDER BY DISTANCE", connection);
SqlCommand command = new SqlCommand($"Select TOP({howMany}) Id, Text, VECTOR_DISTANCE('cosine', CAST(@Embedding AS Vector(1536)), Vector) AS Distance FROM [test].[{_cTableName}] ORDER BY DISTANCE", connection);
Copy link
Collaborator

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

I think that CAST(@Embedding AS Vector(1536)) can be removed as @Embedding is already a vector now


command.Parameters.AddWithValue("@Embedding", JsonSerializer.Serialize(embeddingVector.ToArray()));
command.Parameters.AddWithValue("@Embedding", new SqlVector<float>(embeddingVector.ToArray()));

connection.Open();

Expand Down Expand Up @@ -412,9 +450,9 @@ public async Task LookupNearest(int loops = 100)
{
connection.Open();

SqlCommand command = new SqlCommand($"Select TOP(10) Id, VECTOR_DISTANCE('cosine', CAST(@Embedding AS Vector(1536)), Vector) AS Distance FROM [test].[Vectors] ORDER BY DISTANCE", connection);
SqlCommand command = new SqlCommand($"Select TOP(10) Id, VECTOR_DISTANCE('cosine', CAST(@Embedding AS Vector(1536)), Vector) AS Distance FROM [test].[{_cTableName}] ORDER BY DISTANCE", connection);
Copy link
Collaborator

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

I think that CAST(@Embedding AS Vector(1536)) can be removed as @Embedding is already a vector now


command.Parameters.AddWithValue("@Embedding", JsonSerializer.Serialize(vector));
command.Parameters.AddWithValue("@Embedding", new SqlVector<float>(vector));

using (var reader = await command.ExecuteReaderAsync(System.Data.CommandBehavior.CloseConnection))
{
Expand Down Expand Up @@ -536,12 +574,12 @@ private static async Task InsertVector(string text)

using (SqlConnection connection = new SqlConnection(_cConnStr))
{
string sql = $"INSERT INTO [test].[Vectors] ([Vector], [Text]) VALUES (@Vector, @Text)";
string sql = $"INSERT INTO [test].[{_cTableName}] ([Vector], [Text]) VALUES (@Vector, @Text)";

SqlCommand command1 = new SqlCommand(sql, connection);

// Insert vector as string. Note JSON array.
command1.Parameters.AddWithValue("@Vector", JsonSerializer.Serialize(embeddingVector.ToArray()));
command1.Parameters.AddWithValue("@Vector", new SqlVector<float>(embeddingVector.ToArray()));
command1.Parameters.AddWithValue("@Text", text);

connection.Open();
Expand Down Expand Up @@ -614,7 +652,6 @@ public void VectorSerialization_Tests()
Console.WriteLine("----------------------------------------------");

Console.WriteLine($"j: {jsonResults.Average()} s: {stringResults.Average()}");

}

private static string ToVectorJsonString(float[] embedding)
Expand Down
6 changes: 3 additions & 3 deletions DotNet/SqlClient/Properties/launchSettings.json
Original file line number Diff line number Diff line change
Expand Up @@ -3,9 +3,9 @@
"SqlServer.NativeVectorSearch.Samples": {
"commandName": "Project",
"environmentVariables": {
"ApiKey": "***",
"EmbeddingModelName": "***",
"SqlConnStr": "***"
"ApiKey": "",
"EmbeddingModelName": "",
"SqlConnStr": ""
}
}
}
Expand Down
4 changes: 2 additions & 2 deletions DotNet/SqlClient/SqlServer.NativeVectorSearch.Samples.csproj
Original file line number Diff line number Diff line change
Expand Up @@ -8,8 +8,8 @@
</PropertyGroup>

<ItemGroup>
<PackageReference Include="Microsoft.Data.SqlClient" Version="6.0.1" />
<PackageReference Include="OpenAI" Version="2.0.0" />
<PackageReference Include="Microsoft.Data.SqlClient" Version="6.1.1" />
<PackageReference Include="OpenAI" Version="2.4.0" />
</ItemGroup>

</Project>