Skip to content

Conversation

gentledepp
Copy link

Added support for custom column types.

NOTE: This PR is a draft, since it relies on

  • SQLitePCLraw 3.x
  • the ability to load extensions (for spatialite)

Nevertheless, I wanted to see, if you would be interested in this feature.

We need this feature in order to use spatialite with sqlite-net.
More specifically, to use NetTopologySuite.IO.SpatiaLite

But i can be used to support any custom column type. (e.g. JsonDocument, ...)

That way, we can

  1. define our geometry type directly on our entity:
[Table("buildings")]
public class Building
{
    [PrimaryKey]
    [AutoIncrement]
    public long Id { get; set; }

    public string Name { get; set; }

    public string Address { get; set; }

    public double Price { get; set; }

    public GeometryCollection Geometry { get; set; }
}
  1. insert them like:
using var conn = new SQLiteConnection(GetDatabasePath());
conn.DefineCustomType(new GeometryTypeHandler());
conn.CreateTable<Building>();

var r = new WKTReader(NtsGeometryServices.Instance);

var buildings = new[]
{
    new Building()
    {
        Name = "Eiffel Tower",
        Address = "Champ de Mars, 5 Avenue Anatole France, 75007 Paris, France",
        Geometry = new ([r.Read("POINT(2.2945 48.8584)")]) // Longitude, Latitude
    },
    new Building()
    {
        Name = "Statue of Liberty",
        Address = "Liberty Island, New York, NY 10004, USA",
        Geometry =new ([r.Read( "POINT(-74.0445 40.6892)")])
    },
    new Building()
    {
        Name = "Pentagon",
        Address = "1400 Defense Pentagon, Washington, DC 20301, USA",
        // Pentagon approximate polygon coordinates
        Geometry = new ([r.Read(@"POLYGON((-77.0562 38.8719, -77.0541 38.8690, -77.0581 38.8676, 
                       -77.0602 38.8705, -77.0562 38.8719))")])
    },
    new Building()
    {
        Name = "Great Wall of China",
        Address = "Huairou District, Beijing, China",
        // Sample section of the Great Wall as a linestring
        Geometry = new ([r.Read(@"LINESTRING(116.5704 40.4319, 116.5834 40.4297, 116.5964 40.4275, 
                       116.6094 40.4253, 116.6224 40.4231)")])
    },
    new Building()
    {
        Name = "Place de la Bastille",
        Address = "Place de la Bastille, Paris, France",
        Geometry = new ([r.Read(@"POINT(2.3691386663309313 48.85320759845854)")])
    }
};
conn.InsertAll(buildings);
  1. and perform proximity queries like:
const string proximitySql = @"
        SELECT 
            b.id,
            b.name,
            b.address,
            AsText(b.geometry) as geometry,
            Distance(b.geometry, MakePoint(?, ?, 4326)) * 111000 as distance_meters
        FROM buildings b
        WHERE b.geometry IS NOT NULL
        ORDER BY Distance(b.geometry, MakePoint(?, ?, 4326))
        LIMIT ?"
    ;
var longitude = 2.297260735344715;
var latitude = 48.85917577971452;
var maxResults = 2;

// Act
var b = conn.Query<BuildingProximityResult_WithCustomType>(proximitySql,
    longitude, latitude, longitude, latitude, maxResults);

with BuildingProximityResult_WithCustomType being

    /// <summary>
    /// Represents a building result with proximity distance information.
    /// Used for spatial query results that include distance calculations.
    /// </summary>
    public class BuildingProximityResult_WithCustomType
    {
        /// <summary>Gets or sets the building identifier.</summary>
        public long Id { get; set; }

        /// <summary>Gets or sets the building name.</summary>
        public string Name { get; set; }

        /// <summary>Gets or sets the building address.</summary>
        public string Address { get; set; }

        /// <summary>Gets or sets the geometry in Well-Known Text format.</summary>
        [Column("geometry")]
        public GeometryCollection Geometry { get; set; }

        /// <summary>Gets or sets the distance from query point in meters.</summary>
        [Column("distance_meters")]
        public double DistanceMeters { get; set; }
    }

The only thing required to make it work is implementing a CustomTypeHandler<> with some custom attributes for more flexibility

// Example Geometry handler implementation with custom attributes support
/// <summary>
/// Example handler for spatial geometry types using WKT (Well-Known Text) format
/// </summary>
public class GeometryTypeHandler : CustomTypeHandler<Geometry>
{
    private readonly int _defaultSrid;
    private string _spatialiteVersion;

    /// <summary>
    /// Creates a new geometry handler
    /// </summary>
    /// <param name="defaultSrid">Default Spatial Reference System Identifier (e.g., 4326 for WGS84)</param>
    public GeometryTypeHandler(int defaultSrid = 4326)
    {
        _defaultSrid = defaultSrid;
    }

    public string SpatialiteVersion => _spatialiteVersion;

    public override void Initialize(SQLiteConnection connection)
    {

        connection.EnableLoadExtension(true);
        // Load SpatiaLite extension
        connection.LoadExtension("mod_spatialite");


        // Initialize spatial metadata (only once per database)
        var metadataExists = connection.ExecuteScalar<int>(
            "SELECT COUNT(*) FROM sqlite_master WHERE name = 'spatial_ref_sys'");

        if (metadataExists == 0)
        {
            try
            {
                connection.ExecuteScalar<string>("SELECT InitSpatialMetadata(1)");
            }
            catch (SQLiteException ex) when (ex.Message.Contains("already exists"))
            {
                // Spatial metadata already initialized, continue
            }
        }

        _spatialiteVersion = connection.ExecuteScalar<string>("select spatialite_version()");

    }

    public override string GetSqlType(CustomTypeMetadata metadata)
    {
        var columnType = metadata.Column.ColumnType;

        if (columnType == typeof(Geometry))
            return "GEOMETRYCOLLECTION";
        if (columnType == typeof(LineString))
            return "LINESTRING";
        if (columnType == typeof(Polygon))
            return "POLYGON";
        if (columnType == typeof(MultiPoint))
            return "MULTIPOINT";
        if (columnType == typeof(MultiLineString))
            return "MULTILINESTRING";
        if (columnType == typeof(MultiPolygon))
            return "MULTIPOLYGON";
        if (columnType == typeof(GeometryCollection))
            return "GEOMETRYCOLLECTION";

        throw new NotSupportedException($"The column type '{columnType.FullName}' is not supported");
    }

    public override object ConvertToBindableValue(Geometry value, CustomTypeMetadata metadata)
    {
        return value?.ToString(); // Convert to WKT string
    }

    public override string GetInsertExpression(string parameterPlaceholder, CustomTypeMetadata metadata)
    {
        // Check for custom SRID from attributes, fallback to default
        var srid = GetSridFromMetadata(metadata);
        return $"GeomFromText({parameterPlaceholder}, {srid})";
    }

    public override string GetSelectExpression(string columnName, CustomTypeMetadata metadata)
    {
        return $"AsText(\"{columnName}\")";
    }

    public override Geometry ConvertFromDatabaseValue(object value, CustomTypeMetadata metadata)
    {
        if (value == null || value == DBNull.Value)
            return null;

        var wkt = value.ToString();
        if (string.IsNullOrEmpty(wkt))
            return null;

        // This would use your actual geometry library (NetTopologySuite, etc.)
        return new WKTReader(NtsGeometryServices.Instance).Read(wkt);
    }

    public override (string sql, CommandType commandType) GetAddColumnSql(string tableName, CustomTypeMetadata metadata)
    {
        var srid = GetSridFromMetadata(metadata);
        var geometryType = GetSqlType(metadata);
        var dimensions = GetDimensionsFromMetadata(metadata);

        var sql = $"SELECT AddGeometryColumn('{tableName}', '{metadata.Column.Name}', {srid}, '{geometryType}', '{dimensions}')";
        return (sql, CommandType.ExecuteScalar);
    }

    public override (string sql, CommandType commandType) GetCreateIndexSql(string indexName, string tableName, string columnName,
        bool isUnique, CustomTypeMetadata metadata)
    {
        // Spatial indexes are typically not unique
        return ($"SELECT CreateSpatialIndex('{tableName}', '{columnName}')", CommandType.ExecuteScalar);
    }

    public override void OnTableCreated(SQLiteConnection connection, string tableName, CustomTypeMetadata metadata)
    {
        // Additional setup based on custom attributes
        var constraintAttr = metadata.GetAttribute<GeometryConstraintAttribute>();
        if (constraintAttr != null)
        {
            // Add geometry constraints
            var constraintSql = $"SELECT AddGeometryConstraint('{tableName}', '{metadata.Column.Name}', '{constraintAttr.ConstraintType}')";
            try
            {
                connection.Execute(constraintSql);
            }
            catch (SQLiteException ex)
            {
                // Log or handle constraint creation failure
                Console.WriteLine($"Warning: Could not add geometry constraint: {ex.Message}");
            }
        }
    }

    /// <summary>
    /// Gets the SRID from custom attributes or returns default
    /// </summary>
    private int GetSridFromMetadata(CustomTypeMetadata metadata)
    {
        var sridAttr = metadata.GetAttribute<SridAttribute>();
        return sridAttr?.Srid ?? _defaultSrid;
    }

    /// <summary>
    /// Gets the dimensions from custom attributes or returns default
    /// </summary>
    private string GetDimensionsFromMetadata(CustomTypeMetadata metadata)
    {
        var dimensionsAttr = metadata.GetAttribute<GeometryDimensionsAttribute>();
        return dimensionsAttr?.Dimensions ?? "XY";
    }
}

/// <summary>
/// Specifies the Spatial Reference System Identifier (SRID) for a geometry column
/// </summary>
[AttributeUsage(AttributeTargets.Property | AttributeTargets.Field)]
public class SridAttribute : CustomTypeAttribute
{
    public override string AttributeName => "SRID";

    /// <summary>
    /// The Spatial Reference System Identifier (e.g., 4326 for WGS84)
    /// </summary>
    public int Srid { get; }

    public SridAttribute(int srid)
    {
        Srid = srid;
    }
}

/// <summary>
/// Specifies the dimensions for a geometry column
/// </summary>
[AttributeUsage(AttributeTargets.Property | AttributeTargets.Field)]
public class GeometryDimensionsAttribute : CustomTypeAttribute
{
    public override string AttributeName => "GeometryDimensions";

    /// <summary>
    /// The dimensions (e.g., "XY", "XYZ", "XYM", "XYZM")
    /// </summary>
    public string Dimensions { get; }

    public GeometryDimensionsAttribute(string dimensions)
    {
        Dimensions = dimensions ?? throw new ArgumentNullException(nameof(dimensions));
    }
}

required packages


    <PackageVersion Include="mod_spatialite" Version="4.3.0.1" />
    <PackageVersion Include="NetTopologySuite" Version="2.6.0" />
    <PackageVersion Include="NetTopologySuite.IO.SpatiaLite" Version="2.0.0" />
    <PackageVersion Include="sqlite-net-base" Version="VERSION OF THSI PR ;-)" />
    <PackageVersion Include="SQLitePCLRaw.core" Version="3.0.1" />
    <PackageVersion Include="SQLitePCLRaw.provider.e_sqlite3" Version="3.0.1" /> 
    <PackageVersion Include="SourceGear.sqlite3" Version="3.50.3" />

Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment
Labels
None yet
Projects
None yet
Development

Successfully merging this pull request may close these issues.

2 participants