Preserve start points in UnionAggregate
Originally, I suggested...
DECLARE @Geom TABLE
(
shape geometry,
shapeType nvarchar(50)
);
INSERT @Geom(shape,shapeType) VALUES
('LINESTRING(1 2, 3 4)', 'A'),
('LINESTRING(3.2 4, 7 8)', 'B');
SELECT * FROM @Geom
SELECT
geometry::CollectionAggregate(shape).Reduce(0).ToString(),
geometry::CollectionAggregate(shape).Reduce(0)
FROM @Geom
You get:
...however, it became clear to me that the answer I gave isn't quite good enough. For example, it's kinda hard to keep Reduce()
from simplifying away part of your lines,
I still like the CollectionAggregate for getting your original array of lines into a single thing, but then I figured there just has to be a way of building the requisite geometry structure.
I played with this several times, and this iteration will eval to a LineString
or a MultiLineString
depending on whether there are disjoint LineString
elements in the inputs:
create function dbo.SimplifyToLine( @geo geometry ) returns geometry as
begin
declare
@numSubGeos int = @geo.STNumGeometries(),
@subGeoIdx int = 1,
@sql nvarchar( max ) = N'',
@subGeo geometry,
@oldEndX float = -1.0e26,
@oldEndY float = -1.0e26,
@startX float,
@startY float,
@endX float,
@endY float,
@idx int,
@numPoints int,
@point geometry,
@segment int = 1,
@continue bit,
@result geometry,
@started bit = 0
declare
@geos table
(
Idx int primary key,
SubGeo geometry,
StartX decimal,
EndX decimal,
StartY decimal,
EndY decimal,
NumPoints int,
ContinueFromPrevious bit
)
declare
@multiLines table
(
Idx int primary key,
Segment nvarchar(max)
)
--> collect geometries and extents...
while ( @subGeoIdx <= @numSubGeos )
begin
select @subGeo = @geo.STGeometryN( @subGeoIdx )
select
@startX = @subGeo.STPointN( 1 ).STX,
@startY = @subGeo.STPointN( 1 ).STY,
@endX = @subGeo.STPointN( @subGeo.STNumPoints( ) ).STX,
@endY = @subGeo.STPointN( @subGeo.STNumPoints( ) ).STY
insert @geos values
(
@subGeoIdx,
@subGeo,
@startX,
@endX,
@startY,
@endY,
@subGeo.STNumPoints() ,
case when @subGeoIdx = 1 then 1 when @oldEndX = @startX and @oldEndY = @startY then 1 else 0 end
)
select
@oldEndX = @endX,
@oldEndY = @endY,
@subGeoIdx = @subGeoIdx + 1
end
if not exists ( select * from @geos where ContinueFromPrevious = 0 ) --> then all LineStrings are connected
begin
--> build a single LINESTRING( )...
select @sql = ''
declare c cursor for select SubGeo, StartX, EndX, StartY, EndY, NumPoints, ContinueFromPrevious from @geos order by Idx
open c
while ( 1 = 1 )
begin
fetch next from c into @subGeo, @startX, @endX, @startY, @endY, @numPoints, @continue
if @@fetch_status != 0 break;
select @idx = case when @started = 0 then 1 else 2 end, @started = 1 --> accrue all points, de-duplicating line ends...
while ( @idx <= @numPoints )
begin
select @point = @subGeo.STPointN( @idx )
select @sql += convert( nvarchar, @point.STX ) + N' ' + convert( nvarchar, @point.STY ) + N','
select @idx = @idx + 1
end
end
close c
deallocate c
select @sql = substring( @sql, 1, len( @sql ) -1 )
select @result = geometry::STGeomFromText(N'LINESTRING(' + @sql + N')', 0 )
end
else --> we have disjoint lines in the inputs...
begin
select @sql = N'', @started = 0
--> build a MULTILINESTRING((),()...) with line segements terminated at disjoint points..
declare c cursor for select SubGeo, StartX, EndX, StartY, EndY, NumPoints, ContinueFromPrevious from @geos order by Idx
open c
while ( 1=1 )
begin
fetch next from c into @subGeo, @startX, @endX, @startY, @endY, @numPoints, @continue
if @@fetch_status != 0 break;
if @continue = 1
begin
select @idx = case when @started = 0 then 1 else 2 end, @started = 1
while ( @idx <= @numPoints )
begin
select @point = @subGeo.STPointN( @idx )
select @sql += convert( nvarchar, @point.STX ) + N' ' + convert( nvarchar, @point.STY ) + N','
select @idx = @idx + 1
end
end
else
begin
insert @multiLines values ( @segment, substring( @sql, 1, len( @sql ) -1 ) ) --> collect the segment
select @idx = 1, @sql = N'', @segment = @segment + 1
while ( @idx <= @numPoints )
begin
select @point = @subGeo.STPointN( @idx )
select @sql += convert( nvarchar, @point.STX ) + N' ' + convert( nvarchar, @point.STY ) + N','
select @idx = @idx + 1
end
end
end
close c
deallocate c
insert @multiLines values ( @segment, substring( @sql, 1, len( @sql ) -1 ) )
select @sql = N''
select @sql += N'(' + Segment + N'),' from @multiLines order by Idx --> appends all segments
select @sql = substring( @sql, 1, len( @sql ) -1 )
select @result = geometry::STGeomFromText( 'MULTILINESTRING('+ @sql + N')', 1 )
end
...and finally, given:
DECLARE @Geom TABLE
(
shape geometry,
shapeType nvarchar(50)
);
INSERT @Geom(shape,shapeType) VALUES
('LINESTRING(1 2, 3 4)', 'A'),
('LINESTRING(3 4, 9 9)', 'B'), --> disjoint from here to the next LINESTRING
('LINESTRING(9 8, 3 4)', 'C'),
('LINESTRING(3 4, 1 2)', 'D');
select
dbo.SimplifyToLine(geometry::CollectionAggregate(shape)).ToString(),
dbo.SimplifyToLine(geometry::CollectionAggregate(shape))
from
@Geom
delete @Geom
INSERT @Geom(shape,shapeType) VALUES
('LINESTRING(1 2, 3 4)', 'A'),
('LINESTRING(3 4, 9 8)', 'B'),
('LINESTRING(9 8, 3 4)', 'C'),
('LINESTRING(3 4, 1 2)', 'D');
select
dbo.SimplifyToLine(geometry::CollectionAggregate(shape)).ToString(),
dbo.SimplifyToLine(geometry::CollectionAggregate(shape))
from
@Geom
...you get:
The geometry types don't record/encode directionality. The lines that you give it may be considered "undirected" or "bi-directional". This returns 1:
select geometry::STGeomFromText('LINESTRING(1 2, 3 4)',0).STEquals(
geometry::STGeomFromText('LINESTRING(3 4, 1 2)',0))
So what you're looking for isn't available using these types. You consider the "start points" to be special. I suggest you separately record those as individual POINT
s.
This does make all of the resulting code uglier now though - you have to keep these data pairs processed together:
DECLARE @Geom TABLE
(
start geometry,
shape geometry,
shapeType nvarchar(50)
);
INSERT INTO @Geom(start,shape,shapeType)
VALUES('POINT(1 2)','LINESTRING(1 2, 3 4)', 'A'),
('POINT(3.2 4)','LINESTRING(3.2 4, 7 8)', 'B');
SELECT *
FROM @Geom
SELECT
geometry::UnionAggregate(start).ToString(), geometry::UnionAggregate(shape).ToString(),
geometry::UnionAggregate(start), geometry::UnionAggregate(shape)
FROM @Geom;
At this point you may decide to stop using the geography type directly - you can create a CLR UDT that references SqlGeography
(a CLR surfacing of the same type) and uses that internally but also tracks it's "directionality" too, all wrapped up together, and start using that instead.
You're unlikely to want to surface all of the geography
methods in that wrapper though - you'll have to pick and choose your battles. And, of course, since it's not really the SQL Server geography
turning up in your results, you won't get the benefit of the "Spatial Results" tab in Management Studio.
The only place I can think of where some "directionality" does exist in these types is the left-hand rule for disambiguating geography
shapes.