SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Geometry - Parallel lines


Geometry - Parallel lines

Author
Message
NicHopper
NicHopper
SSCrazy
SSCrazy (3K reputation)SSCrazy (3K reputation)SSCrazy (3K reputation)SSCrazy (3K reputation)SSCrazy (3K reputation)SSCrazy (3K reputation)SSCrazy (3K reputation)SSCrazy (3K reputation)

Group: General Forum Members
Points: 2980 Visits: 1945
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/
K. Brian Kelley
K. Brian Kelley
Keeper of the Duck
Keeper of the Duck (25K reputation)

Group: Moderators
Points: 25864 Visits: 1917
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
@‌kbriankelley
Eirikur Eiriksson
Eirikur Eiriksson
SSC-Forever
SSC-Forever (42K reputation)SSC-Forever (42K reputation)SSC-Forever (42K reputation)SSC-Forever (42K reputation)SSC-Forever (42K reputation)SSC-Forever (42K reputation)SSC-Forever (42K reputation)SSC-Forever (42K reputation)

Group: General Forum Members
Points: 42226 Visits: 19526
This can be done by shifting each point on the line by x and y (@OFFSET_X/Y in the code)
Cool

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:Tonguearse (
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;


mickyT
mickyT
SSCrazy
SSCrazy (2.9K reputation)SSCrazy (2.9K reputation)SSCrazy (2.9K reputation)SSCrazy (2.9K reputation)SSCrazy (2.9K reputation)SSCrazy (2.9K reputation)SSCrazy (2.9K reputation)SSCrazy (2.9K reputation)

Group: General Forum Members
Points: 2916 Visits: 3318
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.
mickyT
mickyT
SSCrazy
SSCrazy (2.9K reputation)SSCrazy (2.9K reputation)SSCrazy (2.9K reputation)SSCrazy (2.9K reputation)SSCrazy (2.9K reputation)SSCrazy (2.9K reputation)SSCrazy (2.9K reputation)SSCrazy (2.9K reputation)

Group: General Forum Members
Points: 2916 Visits: 3318
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:-D

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:Tonguearse (
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:Tonguearse (
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

Attachments
parallel.png (289 views, 11.00 KB)
crmitchell
crmitchell
Ten Centuries
Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)

Group: General Forum Members
Points: 1280 Visits: 1796
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.
NicHopper
NicHopper
SSCrazy
SSCrazy (3K reputation)SSCrazy (3K reputation)SSCrazy (3K reputation)SSCrazy (3K reputation)SSCrazy (3K reputation)SSCrazy (3K reputation)SSCrazy (3K reputation)SSCrazy (3K reputation)

Group: General Forum Members
Points: 2980 Visits: 1945
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/
roy jackson
roy jackson
Grasshopper
Grasshopper (11 reputation)Grasshopper (11 reputation)Grasshopper (11 reputation)Grasshopper (11 reputation)Grasshopper (11 reputation)Grasshopper (11 reputation)Grasshopper (11 reputation)Grasshopper (11 reputation)

Group: General Forum Members
Points: 11 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.
mickyT
mickyT
SSCrazy
SSCrazy (2.9K reputation)SSCrazy (2.9K reputation)SSCrazy (2.9K reputation)SSCrazy (2.9K reputation)SSCrazy (2.9K reputation)SSCrazy (2.9K reputation)SSCrazy (2.9K reputation)SSCrazy (2.9K reputation)

Group: General Forum Members
Points: 2916 Visits: 3318
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 meSmile

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.
crmitchell
crmitchell
Ten Centuries
Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)

Group: General Forum Members
Points: 1280 Visits: 1796
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.
Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum

































































































































































SQLServerCentral


Search