Go to content Go to navigation and search

Home

Current SQL Server Blog Articles

    STGeometryTypes: Extracting all geometry type string values from complex geometry
    STDensify: Densify (m)LineString or (m)Polygon geometry objects
    STInsertN: Insert single vertex into a geometry
    STUpdateN: Update (replace) a single vertex within a geometry object.
    STUpdate: Replace all points equal to the supplied point with replacement point.
    STDeleteN: Delete single vertex from geometry
    STDelete: Deleting vertices in geometry objects
    STFlipVectors: Normalize direction of linestring vectors
    STConvertToLineString: Extract LineStrings in GeometryCollection to create LineString
    STLine2Cogo: Converting LineStrings to COGO XML
    STCogo2Line: Creating (Multi)LineStrings geometries from COGO XML instructions
    STVectorize: Break Linestring/Polygon elements into 2 point vectors (or 3 point circular curves)
    STScale: Function to Scale a geometry object
    TSQL String Tokenizer Function for SQL Server
    STGeometry2MBR/STGeography2MBR: Compute and return MBR ordinates
    generate_series for SQL Server 2008
    STExtractPolygon: Extract Polygons from result of STIntersection in SQL Server Spatial
    STRound: Function to round ordinates of a SQL Server Spatial geometry object
    STExtract: Extract elements of a geometry object
    STNumRings: Counting number of polygon rings
    STFilterRings: Removing rings from Polygon based on area.
    STMove: Function to Move a geometry object in SQL Server Spatial
    STCentroid*: Alternate Functions for Compute a Centroid
    STRotate: Function to rotate a geometry object in SQL Server Spatial
    STVertices: Wrapper over STDumpPoints
    STMorton: Creating a Morton number Space Key value for grid square
    Gridding a geometry or geography object (SQL Server Denali)
    On hinting spatial indexes
    RandomSearchByExtent: Random Search Procedure (2008 Spatial)
    COGO: Convert DMS String to decimal degrees floating point number.
    COGO: Converting (Google Earth) Formatted Longitude/Latitude points to decimal degrees (SQL Server)
    COGO: Convert Degrees, Minutes and Seconds values to Decimal Degrees
    COGO: DD2DMS Formatting a latitude/longitude decimal degree value
    COGO: Create point from bearing and distance
    COGO: Compute number of vertices required to stroke circle or circular arc
    COGO: Calculating the bearing between two points (SQL Server 2008 Spatial)
    COGO: Compute arc length subtended by angle centre of circle
    COGO: Compute chord length of segment of a circle (arc)
    COGO: Computing Arc To Chord (Arc2Chord) Separation
    COGO: Creating a stroked polygon from a circle's centre x,y and radius
    COGO: Finding centre and radius of a curve defined by three points: FindCircle function
    CheckRadii: Identifying Tight Radius Curves sections within LineString geometry data
    Generating random point data for SQL Server 2008 Spatial
    New Presentation on Active (Searchable) Spatial Metadata for SQL Server 2008 Spatial and FreeText
    STisGeo: Checking if a column in a table or a view is of type geometry or geography
    Vectorising geometry objects in SQL Server 2008
    STMBR2Geometry/STMBR2Geography functions
    Extracting geometry types from geometry/geography objects in SQL Server 2008
    Getting the number of coordinate dimensions of a geometry/geography object in SQL Server 2008
    STDumpPoints: A Function that Dumps the Vertices/Points in a geometry
    toGeography and toGeography Conversion Functions for SQL Server 2008 Spatial
    Write text file with spatial data from SQL Server 2008
    Loading Shapefiles into Geography type column in SQL Server 2008
    Tip #6: Correcting invalid geometries
    Tip #5: Where or where has my little column gone
    Tip #4: What Coordinate System is that?
    Tip #3: What object is that?
    Tip #2: Spatial Indexing and Primary Keys
    Tip #1: SQL Server 2008 "Katmai" - Setting SRIDs

Search

    Browse

RSS / Atom

Email me

textpattern

Creative Commons License
All Blog Articles, Data Models and Free Source Code by Simon Greener, The SpatialDB Advisor is licensed under a Creative Commons Attribution-ShareAlike 3.0 Unported License.

Tip #3: What object is that?

Saturday November 24 2007 at 04:22

In Oracle, if I want to know what type of SDO_Geometry object is stored in a column I can do the following:

gis@XE> select a.geom.get_gtype(), count(*)
  2  from tas_lga a
  3* group by a.geom.get_gtype();
A.GEOM.GET_GTYPE()   COUNT(*)
------------------ ----------
                 3          9
                 7         20

However, we have to be able to “interpret” the returned value from get_gtype() in order to understand what the numbers mean. So, let’s “tart up” the output …

gis@XE>  select case a.geom.get_gtype()
  2         when 1 then 'Point'
  3         when 2 then 'Linestring'
  4         when 3 then 'Polygon'
  5         when 4 then 'Collection'
  6         when 5 then 'MultiPoint'
  7         when 6 then 'MultiLineString'
  8         when 7 then 'MultiPolygon'
  9         when 8 then 'MultiCollection' end as gtype
 10         count(*) as Total
 11    from TAS_LGA a
 12*  group by a.geom.get_gtype();
GTYPE             TOTAL
--------------- ----------
Polygon                  9
MultiPolygon            20

But for SQL Server 2008 there is an OGC 1.1 SQL method called STGeometryType() that will return the geography type as follows:

select a.geom.STGeometryType() as gtype,
       COUNT(*) as Total
 from dbo.TAS_LGA a
group by a.geom.STGeometryType();
gtype Total
MULTIPOLYGON 20
POLYGON 9

Adding in dimensionality

Often though we want to know something about the dimensionality of a geometry column. This is pretty easy thing to query out in both databases.

Oracle

With Oracle there are two different geometry functions you can use to query the dimensionality of an sdo_geometry object. One – Get_Dims() – is Oracle specific; the other is part of the SQL3/MM standard – ST_CoordDim():

gis@XE> select a.geom.get_dims(), a.geom.st_coorddim(), count(*)
  2  from TAS_LGA a
  3* group by  a.geom.get_dims(), a.geom.st_coorddim()
gis@XE> /
A.GEOM.GET_DIMS() A.GEOM.ST_COORDDIM()   COUNT(*)
----------------- -------------------- ----------
                2                    2         29

SQL Server 2008

select A.geom.STDimension() as dimension,
       count(*) as Total
  from dbo.TAS_LGA A
group by A.geom.STDimension();
dimension Total
2 29

I hope these tips are useful.

Creative Commons License

post this at del.icio.uspost this at Diggpost this at Technoratipost this at Redditpost this at Farkpost this at Yahoo! my webpost this at Windows Livepost this at Google Bookmarkspost this to Twitter

Comment [1]

One more tip regarding gtypes: you can use the InstanceOf() method to test where the type lies in the OGC hierarchy. E.g.:

declare @g geography
set @g = geography::STGeomFromText(‘LINESTRING[44 0, 45 0]’, 4326)
select @g.InstanceOf(‘geometry’) —returns 1
select @g.InstanceOf(‘curve’) —returns 1
select @g.InstanceOf(‘polygon’) —returns 0

(You need to replace the square brackets above with parenthesis – for some reason if I use parenthesis there the system eats my coordinates.)

Cheers,
-Isaac

Isaac Kunen 24 November 2007, 04:37 #