Click here to monitor SSC
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase

Geometry - Parallel lines Expand / Collapse
Author
Message
Posted Wednesday, March 19, 2014 4:31 AM
SSCommitted

SSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommitted

Group: General Forum Members
Last Login: Tuesday, May 10, 2016 3:37 AM
Points: 1,610, Visits: 1,833
Hi,

Assuming I have a line, is there a function I can call to create a parallel line at a given distance away.

i.e - with the below I would want to draw a parallel line to the one output.

DECLARE @line geometry = 'LINESTRING(1 1, 2 2, 3 3, 4 4)'
SELECT @line

Any help would be appreciated.

Thanks,

Nic


------------------------------------------------------------
Check out my blog

http://www.sqlservercentral.com/articles/Best+Practices/61537/
Post #1552530
Posted Wednesday, March 19, 2014 1:20 PM


Keeper of the Duck

Keeper of the Duck

Group: Moderators
Last Login: Thursday, March 31, 2016 11:36 AM
Points: 6,637, Visits: 1,903
I don't think you're going to find a function with just distance. Maybe with a point. The reason I say this is in 2D space there would be two lines parallel to a give line. In 3D space you'd form a cylinder. So there wouldn't just be a line output in either situation.

K. Brian Kelley, CISA, MCSE, Security+, MVP - SQL Server
Regular Columnist (Security), SQLServerCentral.com
Author of Introduction to SQL Server: Basic Skills for Any SQL Server User
| Professional Development blog | Technical Blog | LinkedIn | Twitter
Post #1552776
Posted Saturday, April 5, 2014 12:48 AM This worked for the OP Answer marked as solution
SSCertifiable

SSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiable

Group: General Forum Members
Last Login: Today @ 10:43 AM
Points: 5,556, Visits: 14,747
This can be done by shifting each point on the line by x and y (@OFFSET_X/Y in the code)


DECLARE @line geometry = 'LINESTRING(1 1, 2 2, 3 3, 4 4, 4 5, 5 7)' ;
DECLARE @pp_line geometry;
DECLARE @OFFSET_X FLOAT = 2;
DECLARE @OFFSET_Y FLOAT = 0;
;WITH NUMBERS(N) AS (SELECT NM.N FROM (VALUES (1),(2),(3),(4),(5),(6),(7),(8),(9),(10)) AS NM(N))

SELECT @pp_line = geometry::Parse (
CONCAT
(
'LINESTRING('
,STUFF((SELECT
CONCAT
(
CHAR(44)
,CHAR(32)
,CAST(@line.STPointN(NM.N).STX + @OFFSET_X AS VARCHAR(12))
,CHAR(32)
,CAST(@line.STPointN(NM.N).STY + @OFFSET_Y AS VARCHAR(12))
) AS [text()]
FROM NUMBERS NM
WHERE NM.N <= @line.STNumPoints()
FOR XML PATH(''), TYPE).value('.[1]','VARCHAR(8000)'),1,1,'')
,CHAR(41)
));
SELECT @pp_line
UNION ALL
SELECT @line;

Post #1558699
Posted Sunday, April 6, 2014 2:42 PM This worked for the OP Answer marked as solution
Ten Centuries

Ten CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen Centuries

Group: General Forum Members
Last Login: Monday, May 9, 2016 9:32 PM
Points: 1,208, Visits: 3,261
Hi

Sorry about the late post, but parallel is always a tricky one. First decision to make is which side of the line do you want to parallel to? The next problem you hit is how do you handle angles greater than 180 degrees in a line string? Do you single point or multiple points at the distance?

Here's some code to parallel to a simple line (2 point)
DECLARE @simpleLineString Geometry = Geometry::STGeomFromText('LINESTRING (0 0, 10 3)',0);
DECLARE @sideMod FLOAT = -1; -- Right = -1, Left = 1
DECLARE @offset FLOAT = .5;

WITH
linePoints AS (
SELECT X1 = @simpleLineString.STPointN(1).STX
,Y1 = @simpleLineString.STPointN(1).STY
,X2 = @simpleLineString.STPointN(2).STX
,Y2 = @simpleLineString.STPointN(2).STY
,L = @simpleLineString.STLength()
)
,calcOffset AS (
SELECT xOffSet = (((Y2 - Y1) * (1 - (L - @offset) / L)) * @sideMod) * -1,
yOffset = ((X2 - X1) * (1 - (L - @offset) / L)) * @sideMod
FROM linePoints
)
,buildParallel AS (
SELECT parallelLine = Geometry::STGeomFromText(
CONCAT('LINESTRING (',
X1 + xOffset,' ',Y1 + yOffset,', ',
X2 + xOffset,' ',Y2 + yOffset,')'), 0)
FROM linePoints l
CROSS APPLY (SELECT * FROM calcOffset) o
)
SELECT 'Original' Name, @simpleLineString Geom
UNION ALL
SELECT 'Parallel' Name, parallelLine Geom
FROM buildParallel;

If you want to do a multi-point line strings you will need to start working out half angles etc.
Post #1558861
Posted Sunday, April 6, 2014 8:03 PM
Ten Centuries

Ten CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen Centuries

Group: General Forum Members
Last Login: Monday, May 9, 2016 9:32 PM
Points: 1,208, Visits: 3,261
Hi

Had a bit of time to play around with a multi point line. The following will do a parallel for both sides of an input geometry. I've left all the calculations exploded out to try and make it a bit easier to follow. There is probably better math for this though

DECLARE @LineString Geometry = Geometry::STGeomFromText('LINESTRING (7 5, 10 3, 11 4, 13 4, 13 -2, 7 1, 5 -2)',0);
DECLARE @offset FLOAT = .5;

WITH cteTally AS (
SELECT ROW_NUMBER() OVER (ORDER BY (SELECT NULL)) N
FROM (VALUES (0),(0),(0),(0),(0),(0),(0),(0),(0),(0)) E1 (N)
,(VALUES (0),(0),(0),(0),(0),(0),(0),(0),(0),(0)) E2 (N)
,(VALUES (0),(0),(0),(0),(0),(0),(0),(0),(0),(0)) E3 (N)
)
,linePoint AS (
SELECT TOP(@LineString.STNumPoints()) N
,X = @LineString.STPointN(N).STX
,Y = @LineString.STPointN(N).STY
,B2Next = CASE WHEN N < @LineString.STNumPoints() THEN
CAST(90 -
DEGREES(
ATN2(
@LineString.STPointN(N + 1).STY - @LineString.STPointN(N).STY,
@LineString.STPointN(N + 1).STX - @LineString.STPointN(N).STX
)
) + 360
AS DECIMAL(38,19)) % 360
END
FROM cteTally
)
,offsetBearings AS (
SELECT b1.N, b1.X, b1.Y, b1.B2Next,
offsetAngleLeft = CASE
WHEN b1.B2Next is NULL THEN b2.B2Next - 90
WHEN b2.B2Next is NULL THEN b1.B2Next - 90
ELSE (360 + b1.B2Next - ((360 - ((b2.B2Next + 180) - b1.B2Next)) / 2)) % 360
END,
offsetAngleRight = CASE
WHEN b1.B2Next is NULL THEN b2.B2Next + 90
WHEN b2.B2Next is NULL THEN b1.B2Next + 90
ELSE (b1.B2Next + ((((b2.B2Next + 180) - b1.B2Next)) / 2)) % 360
END
FROM linePoint b1
LEFT OUTER JOIN linePoint b2 ON b1.N = b2.N + 1
)
,offsetDistance AS (
SELECT *,
offsetDist = CASE
WHEN N = 1 or B2Next is null THEN @offset
ELSE @offset / (SIN(RADIANS(((b2Next - offsetAngleLeft) + 360) % 360)))
END
FROM offsetBearings
)
, parallelCoords AS (
SELECT *
, XL = X + (offsetDist * COS(RADIANS(90 - offsetAngleLeft)))
, YL = Y + (offsetDist * SIN(RADIANS(90 - offsetAngleLeft)))
, XR = X + (offsetDist * COS(RADIANS(90 - offsetAngleRight)))
, YR = Y + (offsetDist * SIN(RADIANS(90 - offsetAngleRight)))
FROM offsetDistance
)
SELECT 'Left' Name, ParallelLineLeft = geometry::Parse (
CONCAT
(
'LINESTRING('
,STUFF((SELECT
CONCAT
(
CHAR(44)
,CHAR(32)
,CAST(XL AS VARCHAR(12))
,CHAR(32)
,CAST(YL AS VARCHAR(12))
) AS [text()]
FROM parallelCoords NM
ORDER BY N
FOR XML PATH(''), TYPE).value('.[1]','VARCHAR(8000)'),1,1,'')
,CHAR(41)
))
UNION ALL
SELECT 'Right' Name, ParallelLineRight = geometry::Parse (
CONCAT
(
'LINESTRING('
,STUFF((SELECT
CONCAT
(
CHAR(44)
,CHAR(32)
,CAST(XR AS VARCHAR(12))
,CHAR(32)
,CAST(YR AS VARCHAR(12))
) AS [text()]
FROM parallelCoords NM
ORDER BY N
FOR XML PATH(''), TYPE).value('.[1]','VARCHAR(8000)'),1,1,'')
,CHAR(41)
))
UNION ALL
SELECT 'Orig' Name, @LineString

Edit Added some ORDER BY clauses in to ensure line vertexes are added in the correct order

Looks like this


  Post Attachments 
parallel.png (155 views, 11.56 KB)
Post #1558884
Posted Wednesday, April 9, 2014 7:48 AM
Old Hand

Old HandOld HandOld HandOld HandOld HandOld HandOld HandOld Hand

Group: General Forum Members
Last Login: Thursday, May 19, 2016 2:30 AM
Points: 357, Visits: 1,437
K. Brian Kelley (3/19/2014)
I don't think you're going to find a function with just distance. Maybe with a point. The reason I say this is in 2D space there would be two lines parallel to a give line. In 3D space you'd form a cylinder. So there wouldn't just be a line output in either situation.


That is only the case where the lines are similar as well as parallel otherwise even in 2D there will still be an infinite number of parallel lines - the length of the line does not affect whether or not it is parallel.

Any straight line in 2d can be defined by the equation y=mx+c bounded by its min and max ordinates. By changing the bounds or the value of c you will generate a parallel line.
Post #1559948
Posted Wednesday, April 9, 2014 7:56 AM
SSCommitted

SSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommitted

Group: General Forum Members
Last Login: Tuesday, May 10, 2016 3:37 AM
Points: 1,610, Visits: 1,833
Hi all,

Thanks for your responses, since the lines in our case are to be the same length we achieved this without to much complexity.

Thank you all for your help.

Nic


------------------------------------------------------------
Check out my blog

http://www.sqlservercentral.com/articles/Best+Practices/61537/
Post #1559957
Posted Wednesday, September 2, 2015 12:43 PM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Friday, November 13, 2015 11:52 AM
Points: 1, Visits: 16
@Ten Centuries

This is nice, however the resulting left and right side lines have the incorrect order of vertices.

Do you know how to fix?

Thanks!


Note - the query produces proper results when running the left side, or the right side, but not when displaying all together. I solved my need by just looking at one side as needed.
Post #1716564
Posted Wednesday, September 2, 2015 7:16 PM
Ten Centuries

Ten CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen Centuries

Group: General Forum Members
Last Login: Monday, May 9, 2016 9:32 PM
Points: 1,208, Visits: 3,261
roy jackson (9/2/2015)
@Ten Centuries

This is nice, however the resulting left and right side lines have the incorrect order of vertices.

Do you know how to fix?

Thanks!


Note - the query produces proper results when running the left side, or the right side, but not when displaying all together. I solved my need by just looking at one side as needed.


I'm going to assume that you are aiming this at me:)

I see what you mean about my original query. It must have worked back when I did, but I just tried it on my current server and can see the problem.

I will edit my original post to fix the issue. It is all around taking the order for granted, which I shouldn't have done.
Post #1716630
Posted Thursday, September 3, 2015 1:43 AM
Old Hand

Old HandOld HandOld HandOld HandOld HandOld HandOld HandOld Hand

Group: General Forum Members
Last Login: Thursday, May 19, 2016 2:30 AM
Points: 357, Visits: 1,437
NicHopper (4/9/2014)
Hi all,

Thanks for your responses, since the lines in our case are to be the same length we achieved this without to much complexity.

Thank you all for your help.

Nic


If you are requiring the lines to be the same length as the original line then you are likely to experience a number of cases where the polylines will cross and some of the line segments may overlap when the offset is forced to be along the length of the original segment.
Post #1716663
« Prev Topic | Next Topic »

Add to briefcase

Permissions Expand / Collapse