diff --git a/by-language/csharp-npgsql/DemoProgram.cs b/by-language/csharp-npgsql/DemoProgram.cs index 1d5098d2..b0670c27 100644 --- a/by-language/csharp-npgsql/DemoProgram.cs +++ b/by-language/csharp-npgsql/DemoProgram.cs @@ -23,6 +23,7 @@ await Parser.Default.ParseArguments(args) await DatabaseWorkloads.SystemQueryExample(conn); await DatabaseWorkloads.BasicConversationExample(conn); await DatabaseWorkloads.UnnestExample(conn); + await DatabaseWorkloadsMore.AllTypesExample(conn); conn.Close(); }); @@ -57,15 +58,19 @@ public static async Task> SystemQueryExample(NpgsqlConnection conn) { Console.WriteLine("Running SystemQueryExample"); var mountains = new List(); - await using (var cmd = new NpgsqlCommand("SELECT mountain FROM sys.summits ORDER BY 1 LIMIT 25", conn)) + const string sql = "SELECT mountain, height, coordinates FROM sys.summits ORDER BY height DESC LIMIT 25"; + await using (var cmd = new NpgsqlCommand(sql, conn)) await using (var reader = cmd.ExecuteReader()) { while (await reader.ReadAsync()) { - mountains.Add(reader.GetString(0)); + mountains.Add( + reader["mountain"].ToString() + " - " + + reader["height"].ToString() + " - " + + reader["coordinates"].ToString()); } - Console.WriteLine($"Mountains: {string.Join(",", mountains)}"); + Console.WriteLine($"Mountains:\n{string.Join("\n", mountains)}"); } Console.WriteLine(); diff --git a/by-language/csharp-npgsql/DemoTypes.cs b/by-language/csharp-npgsql/DemoTypes.cs new file mode 100644 index 00000000..4c9f7546 --- /dev/null +++ b/by-language/csharp-npgsql/DemoTypes.cs @@ -0,0 +1,249 @@ +#nullable enable +using System; +using System.Collections; +using System.Collections.Generic; +using System.Data; +using System.Reflection; +using System.Threading.Tasks; +using Newtonsoft.Json; +using Npgsql; +using NpgsqlTypes; + +namespace demo +{ + + public class AllTypesRecord + { + [JsonProperty("null_integer", NullValueHandling = NullValueHandling.Ignore)] + public int? NullInteger { get; set; } + [JsonProperty("integer")] + public int? Integer { get; set; } + [JsonProperty("bigint")] + public long? Bigint { get; set; } + [JsonProperty("float")] + public float? Float { get; set; } + [JsonProperty("double")] + public double? Double { get; set; } + [JsonProperty("decimal")] + public decimal? Decimal { get; set; } + //[JsonProperty("bit")] + //public BitArray Bit { get; set; } + [JsonProperty("bool")] + public bool? Bool { get; set; } + [JsonProperty("text")] + public string? Text { get; set; } + [JsonProperty("char")] + public string? Char { get; set; } + [JsonProperty("timestamp_tz")] + public string? Timestamp { get; set; } + [JsonProperty("timestamp_notz")] + public string? TimestampNoTz { get; set; } + [JsonProperty("ip")] + public string? Ip { get; set; } + + [JsonProperty("array")] + public IList? Array { get; set; } + [JsonProperty("object")] + public Dictionary? Object { get; set; } + [JsonProperty("geopoint")] + public Dictionary? Geopoint { get; set; } + [JsonProperty("geoshape")] + public Dictionary? Geoshape { get; set; } + [JsonProperty("float_vector")] + public IList? FloatVector { get; set; } + } + + public class DatabaseWorkloadsMore + { + + public static async Task AllTypesExample(NpgsqlConnection conn) + { + Console.WriteLine("Running AllTypesExample"); + + // Submit DDL, create database schema. + await using (var cmd = new NpgsqlCommand("DROP TABLE IF EXISTS testdrive.example", conn)) + { + cmd.ExecuteNonQuery(); + } + + await using (var cmd = new NpgsqlCommand(@" + CREATE TABLE testdrive.example ( + -- Numeric types + null_integer INT, + integer INT, + bigint BIGINT, + float FLOAT, + double DOUBLE, + decimal DECIMAL(8, 2), + -- Other scalar types + bit BIT(8), + bool BOOLEAN, + text TEXT, + char CHARACTER(5), + timestamp_tz TIMESTAMP WITH TIME ZONE, + timestamp_notz TIMESTAMP WITHOUT TIME ZONE, + ip IP, + -- Container types + ""array"" ARRAY(STRING), + ""object"" OBJECT(DYNAMIC), + -- Geospatial types + geopoint GEO_POINT, + geoshape GEO_SHAPE, + -- Vector type + ""float_vector"" FLOAT_VECTOR(3) + ); + ", conn)) + { + cmd.ExecuteNonQuery(); + } + + // Insert single data point. + await using (var cmd = new NpgsqlCommand(@" + INSERT INTO testdrive.example ( + null_integer, + integer, + bigint, + float, + double, + decimal, + bit, + bool, + text, + char, + timestamp_tz, + timestamp_notz, + ip, + ""array"", + ""object"", + geopoint, + geoshape, + float_vector + ) VALUES ( + @null_integer, + @integer, + @bigint, + @float, + @double, + @decimal, + @bit, + @bool, + @text, + @char, + @timestamp_tz, + @timestamp_notz, + @ip, + @array, + @object, + @geopoint, + @geoshape, + @float_vector + ); + ", conn)) + { + Console.WriteLine(cmd); + cmd.Parameters.AddWithValue("null_integer", DBNull.Value); + cmd.Parameters.AddWithValue("integer", 42); + cmd.Parameters.AddWithValue("bigint", 42); + cmd.Parameters.AddWithValue("float", 42.42); + cmd.Parameters.AddWithValue("double", 42.42); + cmd.Parameters.AddWithValue("decimal", 42.42); + cmd.Parameters.AddWithValue("bit", "01010101"); + cmd.Parameters.AddWithValue("bool", true); + cmd.Parameters.AddWithValue("text", "foobar"); + cmd.Parameters.AddWithValue("char", "foo"); + cmd.Parameters.AddWithValue("timestamp_tz", "1970-01-02T00:00:00+01:00"); + cmd.Parameters.AddWithValue("timestamp_notz", "1970-01-02T00:00:00"); + cmd.Parameters.AddWithValue("ip", "127.0.0.1"); + cmd.Parameters.AddWithValue("array", new List{"foo", "bar"}); + // FIXME: System.NotSupportedException: Cannot resolve 'hstore' to a fully qualified datatype name. The datatype was not found in the current database info. + // https://github.com/crate/zk/issues/26 + // cmd.Parameters.AddWithValue("object", new Dictionary(){{"foo", "bar"}}); + cmd.Parameters.AddWithValue("object", @"{""foo"": ""bar""}"); + cmd.Parameters.AddWithValue("geopoint", new List{85.43, 66.23}); + cmd.Parameters.AddWithValue("geoshape", "POLYGON ((5 5, 10 5, 10 10, 5 10, 5 5))"); + cmd.Parameters.AddWithValue("float_vector", new List {1.1, 2.2, 3.3}); + cmd.ExecuteNonQuery(); + } + + // Flush data. + await using (var cmd = new NpgsqlCommand("REFRESH TABLE testdrive.example", conn)) + { + cmd.ExecuteNonQuery(); + } + + // Query back data. + await using (var cmd = new NpgsqlCommand("SELECT * FROM testdrive.example", conn)) + await using (var reader = cmd.ExecuteReader()) + { + var dataTable = new DataTable(); + dataTable.Load(reader); + var payload = JsonConvert.SerializeObject(dataTable); + Console.WriteLine(payload); + return (DataTable) dataTable; + } + + } + + public static async Task ContainerTypesExample(NpgsqlConnection conn) + { + Console.WriteLine("Running AllTypesExample"); + + // Submit DDL, create database schema. + await using (var cmd = new NpgsqlCommand("DROP TABLE IF EXISTS testdrive.container", conn)) + { + cmd.ExecuteNonQuery(); + } + + await using (var cmd = new NpgsqlCommand(@" + CREATE TABLE testdrive.container ( + -- Container types + ""array"" ARRAY(STRING), + ""object"" OBJECT(DYNAMIC) + ); + ", conn)) + { + cmd.ExecuteNonQuery(); + } + + // Insert single data point. + await using (var cmd = new NpgsqlCommand(@" + INSERT INTO testdrive.container ( + ""array"", + ""object"" + ) VALUES ( + @array, + @object + ); + ", conn)) + { + Console.WriteLine(cmd); + // FIXME: While doing conversations with ARRAY types works natively, + // it doesn't work for OBJECT types. + // Yet, they can be submitted as STRING in JSON format. + cmd.Parameters.AddWithValue("array", new List{"foo", "bar"}); + cmd.Parameters.AddWithValue("object", @"{""foo"": ""bar""}"); + cmd.ExecuteNonQuery(); + } + + // Flush data. + await using (var cmd = new NpgsqlCommand("REFRESH TABLE testdrive.container", conn)) + { + cmd.ExecuteNonQuery(); + } + + // Query back data. + await using (var cmd = new NpgsqlCommand("SELECT * FROM testdrive.container", conn)) + await using (var reader = cmd.ExecuteReader()) + { + var dataTable = new DataTable(); + dataTable.Load(reader); + var payload = JsonConvert.SerializeObject(dataTable); + Console.WriteLine(payload); + return (DataTable) dataTable; + } + + } + + } + +} diff --git a/by-language/csharp-npgsql/README.rst b/by-language/csharp-npgsql/README.rst index 60e9855b..ee47ee1b 100644 --- a/by-language/csharp-npgsql/README.rst +++ b/by-language/csharp-npgsql/README.rst @@ -71,6 +71,21 @@ For running tests selectively, use:: dotnet test --framework=net8.0 --filter SystemQueryExample +Troubleshooting +=============== + +If you observe an error like this when invoking the program or test case:: + + Microsoft.PackageDependencyResolution.targets(266,5): error NETSDK1005: + Assets file '/path/to/csharp-npgsql/obj/project.assets.json' doesn't have a target for 'net9.0'. + Ensure that restore has run and that you have included 'net9.0' in the TargetFrameworks for your project. + +please adjust ``demo.csproj`` like that:: + +- net6.0;net8.0 ++ net6.0;net8.0;net9.0 + + .. _C#: https://en.wikipedia.org/wiki/C_Sharp_(programming_language) .. _crate-npgsql: https://github.com/crate/crate-npgsql .. _Npgsql - .NET Access to PostgreSQL: https://github.com/npgsql/npgsql diff --git a/by-language/csharp-npgsql/tests/DemoProgramTest.cs b/by-language/csharp-npgsql/tests/DemoProgramTest.cs index 77c10e0a..fc49e73e 100644 --- a/by-language/csharp-npgsql/tests/DemoProgramTest.cs +++ b/by-language/csharp-npgsql/tests/DemoProgramTest.cs @@ -1,12 +1,14 @@ using System; using System.Collections.Generic; +using System.Data; +using System.Linq; using System.Threading.Tasks; using Npgsql; using Xunit; namespace demo.tests { - + public class DatabaseFixture : IDisposable { public NpgsqlConnection Db { get; private set; } @@ -29,10 +31,10 @@ public void Dispose() } } - + public class DemoProgramTest : IClassFixture { - + DatabaseFixture fixture; DatabaseWorkloads program = new DatabaseWorkloads(); @@ -51,7 +53,7 @@ public async Task TestSystemQueryExample() var mountains = await task.WaitAsync(TimeSpan.FromSeconds(0.5)); // Check results. - Assert.Equal("Acherkogel", mountains[0]); + Assert.Equal("Mont Blanc - 4808 - (6.86444,45.8325)", mountains[0]); } [Fact] @@ -79,6 +81,91 @@ public async Task TestUnnestExample() // Check results. Assert.Equal(10, resultCount); } - + + [Fact] + public async Task TestAllTypesExample() + { + var conn = fixture.Db; + + // Invoke database workload. + var task = DatabaseWorkloadsMore.AllTypesExample(conn); + var dt = await task.WaitAsync(TimeSpan.FromSeconds(0.5)); + + // Check results. + var row = dt.Rows[0]; + + // Numeric types + Assert.Equal(DBNull.Value, row["null_integer"]); + Assert.Equal(42, row["integer"]); + Assert.Equal((Int64) 42, row["bigint"]); + Assert.Equal(42.42, (float) row["float"], 0.01); + Assert.Equal(42.42, (double) row["double"], 0.01); + Assert.Equal(new decimal(42.42), row["decimal"]); + + // Other scalar types + Assert.Equal(new List { false, true, false, true, false, true, false, true }, row["bit"]); + Assert.True((bool) row["bool"]); + Assert.Equal("foobar", row["text"]); + Assert.Equal("foo ", row["char"]); + Assert.Equal(DateTime.Parse("1970-01-01T23:00:00.0000000"), row["timestamp_tz"]); + Assert.Equal(DateTime.Parse("1970-01-02T00:00:00"), row["timestamp_notz"]); + Assert.Equal("127.0.0.1", row["ip"]); + + // Container types + // FIXME: While doing conversations with ARRAY types works natively, + // it doesn't work for OBJECT types. + // Yet, they can be submitted as STRING in JSON format. + Assert.Equal(new List{"foo", "bar"}, row["array"]); + Assert.Equal(@"{""foo"":""bar""}", row["object"]); + + // Geospatial types + // TODO: Unlock native data types? + // GEO_POINT and GEO_SHAPE types can be marshalled back and forth using STRING. + // GEO_POINT is using a tuple format, GEO_SHAPE is using the GeoJSON format. + // Assert.Equal(new List{85.43, 66.23}, row["geopoint"]); // TODO + Assert.Equal("(85.42999997735023,66.22999997343868)", row["geopoint"].ToString()); // FIXME + Assert.Equal(@"{""coordinates"":[[[5.0,5.0],[5.0,10.0],[10.0,10.0],[10.0,5.0],[5.0,5.0]]],""type"":""Polygon""}", row["geoshape"]); + + // Vector type + Assert.Equal((new List{1.1, 2.2, 3.3}).Select(d => (float) d).ToArray(), row["float_vector"]); + } + + [Fact] + public async Task TestContainerTypesExample() + { + var conn = fixture.Db; + + // Invoke database workload. + var task = DatabaseWorkloadsMore.ContainerTypesExample(conn); + var dt = await task.WaitAsync(TimeSpan.FromSeconds(0.5)); + + // Check results. + var row = dt.Rows[0]; + // FIXME: While doing conversations with ARRAY types works natively, + // it doesn't work for OBJECT types. + // Yet, they can be submitted as STRING in JSON format. + Assert.Equal(new List{"foo", "bar"}, row["array"]); + Assert.Equal(@"{""foo"":""bar""}", row["object"]); + + // Run a special query indexing into ARRAY types. + await using (var cmd = new NpgsqlCommand(@"SELECT ""array[2]"" AS foo FROM testdrive.container", conn)) + await using (var reader = cmd.ExecuteReader()) + { + var dataTable = new DataTable(); + dataTable.Load(reader); + Assert.Equal("bar", dataTable.Rows[0]["foo"]); + } + + // Run a special query indexing into OBJECT types. + await using (var cmd = new NpgsqlCommand(@"SELECT ""object['foo']"" AS foo FROM testdrive.container", conn)) + await using (var reader = cmd.ExecuteReader()) + { + var dataTable = new DataTable(); + dataTable.Load(reader); + Assert.Equal("bar", dataTable.Rows[0]["foo"]); + } + + } + } }