Go to content Go to navigation and search

Home

Current Oracle Spatial Blog Articles

    Tip: Drop that Spatial Index!
    Convert Single Geometry to Multi-part Geometry in Oracle Spatial
    Optimized Rectangle to 5 Point Polygon
    Centroid Package now supports Y ordinate seeding
    Convert GeoJSON document to Sdo_Geometry objects
    Implementation Of Travelling Salesman Problem
    Create Polygon From Bearings And Distances
    Function That Returns a Compass Point From a Whole Circle Bearing
    Playing around with Centroids by using different seed values
    GeoRaptor 4.x Update 2
    Simple Oracle C Sprintf or Java String.format
    Some Oriented Point Functions
    Extracting Inner Rings Changed Ordinate Ordering: A Trap For Players Who Don't Read Documentation!
    PLS-00306: wrong number or types of arguments in call to 'SDO_GEOMETRY'
    Converting Google Earth Formatted Longitude/Latitude points to decimal degrees
    Oracle Business Intelligence Warehousing and Analytics - Spatial Summit
    How far inside, is inside? Measuring actual distance.
    Noding and building a polygon from single, overlapping linestrings
    Analyzing Spatial Query Performance Improvements in Oracle Spatial and Graph 12c Through Cross-Vendor Comparison
    ST_VertexN / ST_PointN - Extracting a specific point from any geometry
    Convert Single Point stored in SDO_ORDINATES to SDO_POINT_TYPE
    Aggregate APPEND Islands and XOR polygons
    Circular Arcs in Geodetic Polygons
    Some SDO_GEOMETRY/DIMINFO handling functions
    Applying And Extending Oracle Spatial - Book Released
    Changing all DIMINFO sdo_tolerance values for all metadata records in one go.
    Building Polygons from Incomplete Linestrings using ST_PolygonBuilder
    Computing Cardinal Directions to nearby geometries
    Intersecting two aggregated polygon layers with SC4O
    Spatial and Oracle 12c
    Update Triggers and SDO_GEOMETRY Equality
    Duplicate Geometry data and Data Models
    CENTROID package update
    How to calculate cumulative length of a linestring
    Useful Package of Wrapper Functions for Sdo_Util.AffineTransforms
    Compute Location from known Lat/Long point using delta easting and northing in miles
    SDO_AGGR_SET_UNION
    Sorting SDO_GEOMETRY data using the ORDER BY clause of a SELECT statement
    Creating linestrings from points
    Rounding Coordinates or Ordinates in SDO_GEOMETRY
    Effects of Sdo_Geometry Ordinate Precision on Performance
    Effects of Sdo_Geometry Ordinate Precision on Storage
    The Spatial filtering of geometries: The effect of tolerances on relationships
    Application of Delaunay Triangulation and Inverse Distance Weighting (IDW) in Oracle for Soils Interpolation
    Selecting all SDO_GTYPE values for all tables/sdo_geometry columns in a schema
    CENTROID package - Tips for Use
    Announcing the Spatial Companion For Oracle (SC4O)
    Filtering Rings (Oracle Spatial)
    Splitting a polygon using one or more linestrings
    isValid, isSimple, Dimension and CoordDim methods for SDO_Geometry
    Line Merging or Collecting lines together: ST_LineMerger
    ST_DeleteVertex for Oracle SDO_Geometry based on Jaspa/JTS
    3D/4D and SRID aware Conversion functions for SDO_Geometry: WKT and EWKT
    Topological vs Non-Topological Simplification/Generalization of Aggregated Area Geometies in Oracle
    Filtering very short linestrings via bitmap function index
    CENTROID For Oracle
    Gridding a sdo_geometry line/polygon object (Oracle)
    Finding centre and radius of a circular geometry
    Constraining geometry type for sdo_geometry column in a table.
    CASE Statements and SDO_GEOMETRY
    The Power of Constraints and Indexes for Spatial Constraints: stopping duplicate points
    Replacement for SDO_GEOM.RELATE - ST_Relate based on JTS
    Changing Oracle Spatial Index Parameters on existing index
    Writing Excel Spreadsheets files from within the Oracle database using Java and PL/SQL
    Writing xSV (eg csv) files from within the Oracle database using Java and PL/SQL
    A simple spike finder for Spatial/Locator
    JTS Java class compilation for 11g and above
    Random Spatial Search Procedure
    Geometry Snapping using JTS in Oracle
    Exposing JTS's MinimumBoundingCircle functionality
    Exposing JTS's Densifier functionality
    Using JTS's Comparison Functions - HausdorffSimilarityMeasure & AreaSimilarityMeasure with SDO_GEOMETRY
    Free JTS-based Area/Length Functions
    Handy way of systematically fixing polygon geometries with 13349 and other errors
    Standalone CENTROID package now available for download
    Free Union, Intersection, Xor and Difference Functions for Oracle Locator - Part 4 Processing Geodetic data
    Configurable Buffer: JTS and Oracle
    Free Union, Intersection, Xor and Difference Functions for Oracle Locator - Part 3
    Free Union, Intersection, Xor and Difference Functions for Oracle Locator - Part 2
    Free Union, Intersection, Xor and Difference Functions for Oracle Locator - Part 1
    Building Lines into Polygons in Oracle Locator / Spatial
    Finding Intersection Points between Line and Polygon
    SDO2GeoJSON
    Free version of sdo_length
    Alternative to my SQL based GetNumRings function
    External Tables and SDO_Geometry data.
    layer_gtype keyword issue when indexing linear data on 11g
    String Tokenizer for Oracle
    Free Aggregate Method for Concatenating 2D Lines in Oracle Locator 10g
    Reducing 5 Vertex Polygon to Optimized Rectangle
    Square Buffer
    Converting decimal seconds to string
    SDO_GEOM.VALIDATE_GEOMETRY_WITH_CONTEXT - 13356 Issues
    Valid conversion unit values for Oracle sdo_geom.sdo_length()
    Removing Steps in Gridded Vector Data - SmoothGrid for Oracle
    Oracle Spatial DISJOINT search/filtering
    Creating SDO_Geometry from geometric data recorded in the columns of a table
    Concave Hull Geometries in Oracle 11gR2
    Projecting SDO_GEOM_METADATA DIMINFO XY ordinates
    Instantiating MDSYS.VERTEX_TYPE
    New PL/SQL Packages - Rotate oriented point
    GeoRaptor Development Team
    Fast Refreshing Materialized View Containing SDO_GEOMETRY and SDO_GEOM.SDO_AREA function
    Performance of PL/SQL Functions using SQL vs Pure Code
    Implementing the BEST VicGrid Projection in Oracle 10gR2
    Making Sdo Geometry Metadata Update Generic Code
    ORA-13011 errors when using SDO_GEOM.VALIDATE_LAYER_WITH_CONTEXT()
    Extract Polygons from Compound Polygon
    Detecting sdo_geometries with compound (3-point Arcs) segments
    GEOMETRY_COLUMNS for Oracle Spatial
    Convert GML to SDO_Geometry in Oracle 10gR2
    Spatial Sorting of Data via Morton Key
    Swapping Ordinates in an SDO_GEOMETRY object
    New To_3D Function
    Extend (Reduce/Contract/Skrink) Function for Oracle
    Loading and Processing GPX 1.1 files using Oracle XMLDB
    Loading Spatial Data from an external CSV file in Oracle
    Calling the Oracle Spatial shapefile loader from within the Oracle database itself
    Implementing SDO_VertexUpdate/ST_VertexUpdate for Oracle
    Implementing SDO_RemovePoint/ST_RemovePoint for Oracle
    Implementing SDO_AddPoint/ST_AddPoint for Oracle
    ESRI ArcSDE Exverted and Inverted Polygons and Oracle Spatial
    Funky Fix Ordinates By Formula
    Implementing a SetPoint/ST_SetPoint function in Oracle
    Implementing an ST_SnapToGrid (PostGIS) function for Oracle Spatial
    Generating random point data
    Implementing an Affine/ST_Affine function for Oracle Spatial
    Implementing a Scale/ST_Scale function for Oracle Spatial
    Implementing a Parallel/ST_Parallel function for linestring data for Oracle Spatial
    Implementing a Rotate/ST_Rotate function for Oracle Spatial
    Limiting table list returned when connecting to Oracle Database using ODBC
    ST_Azimuth for Oracle: AKA Cogo.Bearing
    Implementing a Translate/ST_Translate/Move function for Oracle Spatial
    Elem_Info_Array Processing: An alternative to SDO_UTIL.GetNumRings and querying SDO_ELEM_INFO itself
    Minumum Bounding Rectangle (MBR) Object Type for Oracle
    How to extract elements from the result of an sdo_intersection of two polygons.
    How to restart a database after failed parameter change
    Fixing failed spatial indexes after import using data pump
    generate_series: an Oracle implementation in light of SQL Design Patterns
    Multi-Centroid Shootout
    Oracle Spatial Centroid Shootout
    On the use of ROLLUP in Oracle SELECT statements
    Surrounding Parcels
    Spatial Pipelining
    Using Oracle's SDO_NN Operator - Some examples
    Converting distances and units of measure in Oracle Locator
    Split Sdo_Geometry Linestring at a known point
    Forcing an Sdo_Geometry object to contain only points, lines or areas
    Unpacking USER_SDO_GEOM_METADATA's DIMINFO structure using SQL
    Generating multi-points from single point records in Oracle Spatial
    Object Tables of Sdo_Geometry
    Oracle Locator vs Oracle Spatial: A Reflection on Oracle Licensing of the SDO_GEOM Package
    FAST REFRESHing of Oracle Materialized Views containing Sdo_Geometry columns
    Australian MGA/AMG Zone Calculation from geographic (longitude/latitude) data
    Loading Shapefiles (SHP) into Oracle Spatial
    Oracle Spatial Mapping and Map Rendering Performance Tips
    The significance of sdo_lb/sdo_ub in USER_SDO_GEOM_METDATA: Do I need it?
    Oracle Spatial Forum - Melbourne April 2007
    Layer_GTypes for spatial indexes
    Oracle's SQL/MM Compliant Types
    Tips and Tricks

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.

generate_series: an Oracle implementation in light of SQL Design Patterns

Thursday November 06 2008 at 05:47

Keywordsseries of integers generate_series oracle
Summary

This article shows how the many methods of generating an integer series of numbers in Oracle in light of Sql Design patterns. In particular it shows how to implement the Postgresql system function generate_series for Oracle.

There is a very useful function in PostgreSQL called generate_series that can be used to generate a series of integer numbers from some start value to an end value with an optional step value.

Here is the function and its description from the PostgreSQL help.

Function Argument Type Return Type Description
generate_series(start, stop) int or bigint setof int or setof bigint (same as argument type) Generate a series of values, from start to stop with a step size of one
generate_series(start, stop, step) int or bigint setof int or setof bigint (same as argument type) Generate a series of values, from start to stop with a step size of step

There are a number of ways we can code this function in Oracle. Since the original function is a “set returning function”, we need to code generate_series so that it returns a table of numbers:

  1. TYPE t_numbers IS TABLE OF NUMBER;

The most efficient way to do this is via a PIPELINED function, so that is what I will code.

  1. CREATE OR REPLACE
  2.  FUNCTION generate_series(p_start IN pls_integer,
  3.                            p_end   IN pls_integer,
  4.                            p_step  IN pls_integer := 1 )
  5.        RETURN CODESYS.centroid.t_numbers PIPELINED
  6.   AS
  7.     v_i    PLS_INTEGER := CASE WHEN p_start IS NULL THEN 1 ELSE p_start END;
  8.     v_step PLS_INTEGER := CASE WHEN p_step IS NULL OR p_step = 0 THEN 1 ELSE p_step END;
  9.     v_terminating_value PLS_INTEGER :=  p_start + TRUNC(ABS(p_start-p_end) / abs(v_step) ) * v_step;
  10.   BEGIN
  11.      -- Check for impossible combinations
  12.      IF ( p_start > p_end AND SIGN(p_step) = 1 )
  13.         OR
  14.         ( p_start < p_end AND SIGN(p_step) = -1 ) THEN
  15.        RETURN;
  16.      END IF;
  17.      -- Generate integers
  18.      LOOP
  19.        PIPE ROW ( v_i );
  20.        EXIT WHEN ( v_i = v_terminating_value );
  21.        v_i := v_i + v_step;
  22.      END Loop;
  23.      RETURN;
  24.   END generate_series;
  25. /
  26. SHOW errors

Now, to run the tests on the PostgreSQL help page:

Let’s start with a simple, additional, example not on the page.

  1. SELECT g.column_value AS generate_series
  2.   FROM TABLE(generate_series(1,5)) g;
  3. -- Results
  4. GENERATE_SERIES
  5. ----------------------
  6. 1
  7. 2
  8. 3
  9. 4
  10. 5
  11. .
  12. 5 ROWS selected
  13. --
  14. -- Now, let's execute the ones on the help page.
  15. --
  16. SELECT g.column_value AS generate_series
  17.   FROM TABLE(generate_series(2,4)) g
  18. -- Results
  19. GENERATE_SERIES
  20. ---------------
  21.               2
  22.               3
  23.               4
  24. .
  25. 3 ROWS selected.
  26. --
  27. -- Another
  28. --
  29. SELECT g.column_value AS generate_series
  30.   FROM TABLE(generate_series(5,1,-2)) g
  31. -- Results
  32. GENERATE_SERIES
  33. ---------------
  34.               5
  35.               3
  36.               1
  37. .
  38. 3 ROWS selected.
  39. --
  40. -- And again
  41. --
  42. SELECT g.column_value AS generate_series
  43.   FROM TABLE(generate_series(4,3)) g
  44. -- Results
  45. no ROWS selected
  46. --
  47. --With one additional:
  48. --
  49. SELECT g.column_value AS generate_series
  50.   FROM TABLE(generate_series(-4,-1,1)) g
  51. -- Results
  52. GENERATE_SERIES
  53. ---------------
  54.              -4
  55.              -3
  56.              -2
  57.              -1
  58. .
  59. 4 ROWS selected.
  60. --
  61. -- And finally.
  62. --
  63. SELECT to_char(CURRENT_DATE + sa.column_value,'YYYY-MM-DD') AS da
  64.   FROM TABLE(generate_series(0,14,7)) sa
  65. -- Results
  66.      DATES
  67. ----------
  68. 2008-11-06
  69. 2008-11-13
  70. 2008-11-20
  71. .
  72. 3 ROWS selected.

Alternative Table Function

Now all this is very good, but there is some debate as to implementing a series of integers in this way.

Vadim Tropashko, in his excellent book, “SQL Design Patterns, The Expert Guide to SQL Programming”, Rampart Press has a whole chapter (2) devoted to “Integer Generators in SQL”. In this chapter, Vadmin presents an coding of a simple Integer generating table function called “Integers”. His coding is as follows.

  1. CREATE OR REPLACE FUNCTION Integers
  2.        RETURN t_integers PIPELINED
  3. AS
  4. BEGIN
  5.    Loop
  6.      PIPE ROW ( 0 );
  7.    END Loop;
  8.    RETURN;
  9. END Integers;

We will now use this function to implement the PostgreSQL help examples above.

Firstly, generating numbers between 1 and 5.

  1. SELECT rownum AS rin
  2.   FROM TABLE(Integers)
  3.  WHERE rownum <= 5
  4. -- Results
  5.        RIN
  6. ----------
  7.          1
  8.          2
  9.          3
  10.          4
  11.          5
  12. .
  13. 5 ROWS selected.
  14. --
  15. -- All numbers between 2 and 4.
  16. --
  17. SELECT rin
  18.   FROM (SELECT rownum AS rin
  19.           FROM TABLE(Integers)
  20.          WHERE rownum <= 5)
  21.  WHERE rin BETWEEN 2 AND 4
  22. -- Results
  23.        RIN
  24. ----------
  25.          2
  26.          3
  27.          4
  28. .
  29. 2 ROWS selected.
  30. --
  31. -- Series 5,3,1 using a step of -2.
  32. --
  33. SELECT rin
  34.   FROM (SELECT 5 + ((rownum-1) * -1) AS rin
  35.           FROM TABLE(Integers)
  36.          WHERE rownum < 10)
  37.  WHERE rin BETWEEN 1 AND 5
  38.    AND MOD(rin,ABS(-2)) = 1;
  39. -- Results
  40.        RIN
  41. ----------
  42.          5
  43.          3
  44.          1
  45. .
  46. 3 ROWS selected

I won’t code the invalid series. So let’s move on to the negative series.

  1. SELECT rin
  2.   FROM (SELECT -1 + (rownum - 1 ) * -1 AS rin
  3.           FROM TABLE(Integers)
  4.          WHERE rownum < 10
  5.          ORDER BY 1)
  6.  WHERE rin BETWEEN -4 AND -1;
  7. -- Results
  8.        RIN
  9. ----------
  10.         -4
  11.         -3
  12.         -2
  13.         -1
  14. .
  15. 4 ROWS selected
  16. --
  17. -- And finally.
  18. --
  19. SELECT to_char(CURRENT_DATE + sa.rin,'YYYY-MM-DD') AS dates
  20.   FROM (SELECT (rownum - 1) AS rin
  21.           FROM TABLE(Integers)
  22.          WHERE rownum <= 15) sa
  23.  WHERE MOD(rin,7) = 0;
  24. -- Results
  25.      DATES
  26. ----------
  27. 2008-11-06
  28. 2008-11-13
  29. 2008-11-20
  30. .
  31. 3 ROWS selected.

Hierarchical Queries

Vadim goes on in his book to describe the use of hierarchical queries for generating integer series. Here is an example of how to generate all even numbers between 5 and 8.

  1. SELECT level
  2.   FROM dual
  3.  WHERE level BETWEEN 5 AND 8
  4.    AND MOD(level,2) = 0
  5.   CONNECT BY level <= 10
  6. -- Results
  7.      LEVEL
  8. ----------
  9.          6
  10.          8
  11. .
  12. 2 ROWS selected.
  13. --
  14. -- And the negative series -4,-3,-2,-1 above.
  15. --
  16. SELECT level * -1
  17.   FROM dual
  18.  WHERE level BETWEEN 1 AND 4
  19.  CONNECT BY level <= 5
  20.  ORDER BY level DESC;
  21. -- Results
  22.      LEVEL
  23. ----------
  24.         -4
  25.         -3
  26.         -2
  27.         -1
  28. .
  29. 4 ROWS selected

I am a big fan of hierachical queries and have used them a lot in my work but mainly in the area of generating sample data (see other articles in this blog for examples). My personal view is that coding integer ranges with the “connect by level” hierarchical query is simpler to use and code than the Integers() function. However, the “connect by level” usage above does not work in versions of Oracle before 10g. So all you 9i users will have to resort to coding a suitable table function.

Application to Oracle Spatial Data Processing

Since 11g, Oracle has included a function called SDO_UTIL.EXTRACT that can be used to extract the elements of an SDO_GEOMETRY object. For example, it can be used to extract the linestrings in a multilinestring object or the polygons in a multipolygon object.

In addition, Oracle has a function called SDO_UTIL.GetNumElem which can return the number of polygons/linestrings in a multipolygon/multilinestring.

I will show how to use both the generate_series and CONNECT BY LEVEL approaches to extracting single geometries from a multigeometry.

CONNECT BY LEVEL

  1. WITH mGeom AS (
  2. SELECT rownum AS id,
  3.        sdo_geometry(2006,NULL,NULL,
  4.                     sdo_elem_info_array(1,2,1,
  5.                                         5,2,1,
  6.                                         9,2,1),
  7.                     sdo_ordinate_array(1,1,10,10,
  8.                                        20,1,50,50,
  9.                                        100,0,150,50)) AS geom
  10.   FROM dual
  11. )
  12. SELECT id,
  13.        line_id,
  14.        mdsys.sdo_util.GetNumElem(p.geom) AS line_Count,
  15.        mdsys.sdo_util.EXTRACT(p.geom,line_id,0) AS geom
  16.     FROM mGeom p,
  17.         (SELECT level AS line_id
  18.           FROM dual
  19.           CONNECT BY level <= (SELECT MAX(mdsys.sdo_util.GetNumElem(p.geom)) FROM mGeom p) ) i
  20.    WHERE i.line_id <= mdsys.sdo_util.GetNumElem(p.geom)
  21. ORDER BY 1,2;
  22. --
  23. -- Results
  24. --
  25. ID LINE_ID LINE_COUNT GEOM
  26. -- ------- ---------- ----------------------------------------------------------------------------------------
  27. 1  1       3          SDO_GEOMETRY(2002,NULL,NULL,SDO_ELEM_INFO_ARRAY(1,2,1),SDO_ORDINATE_ARRAY(1,1,10,10))
  28. 1  2       3          SDO_GEOMETRY(2002,NULL,NULL,SDO_ELEM_INFO_ARRAY(1,2,1),SDO_ORDINATE_ARRAY(20,1,50,50))
  29. 1  3       3          SDO_GEOMETRY(2002,NULL,NULL,SDO_ELEM_INFO_ARRAY(1,2,1),SDO_ORDINATE_ARRAY(100,0,150,50))

That query, I think, is unnecessarily complicated. Let’s try generate_series.

  1. WITH mGeom AS (
  2. SELECT rownum AS id,
  3.        sdo_geometry(2006,NULL,NULL,
  4.                     sdo_elem_info_array(1,2,1,
  5.                                         5,2,1,
  6.                                         9,2,1),
  7.                     sdo_ordinate_array(1,1,10,10,
  8.                                        20,1,50,50,
  9.                                        100,0,150,50)) AS geom
  10.   FROM dual
  11. )
  12. SELECT id,
  13.        i.column_value AS line_id,
  14.        mdsys.sdo_util.GetNumElem(p.geom) AS Line_Count,
  15.        mdsys.sdo_util.EXTRACT(p.geom,i.column_value,0) AS geom
  16.     FROM mGeom p,
  17.          TABLE(geom.generate_series(1,mdsys.sdo_util.GetNumElem(p.geom),1)) i
  18. ORDER BY 1,2;
  19. --
  20. -- Results
  21. --
  22. ID LINE_ID LINE_COUNT GEOM
  23. -- ------- ---------- ----------------------------------------------------------------------------------------
  24. 1  1       3          SDO_GEOMETRY(2002,NULL,NULL,SDO_ELEM_INFO_ARRAY(1,2,1),SDO_ORDINATE_ARRAY(1,1,10,10))
  25. 1  2       3          SDO_GEOMETRY(2002,NULL,NULL,SDO_ELEM_INFO_ARRAY(1,2,1),SDO_ORDINATE_ARRAY(20,1,50,50))
  26. 1  3       3          SDO_GEOMETRY(2002,NULL,NULL,SDO_ELEM_INFO_ARRAY(1,2,1),SDO_ORDINATE_ARRAY(100,0,150,50))

Both work nicely, but I rather prefer the cleanliness of the generate_series query.

Conclusion

Tropashko’s preference (as also Mikito Harakiri) in coding an integer series generation table function is to code one without parameters, such as Integers(), and not like generate_series. The main reason is that he prefers the use of predicates in SQL SELECT statements (such as “rownum < = 1000”) than parameters passed to a function. This is because they are at a “higher abstraction level”, claiming that “programs with predicate expressions are shorter and cleaner”. Because I am a “SQL man”, preferring a single SQL statement to complex PL/SQL, and because I like things to be done “orthogonally”, “theoretically” and via patterns/templates I am tempted to agree with Tropashko. However, when I look at the SQL above, I find the generate_series implementation much, much cleaner and less complicated.

The problem with the Integers() function is that it forces me to “reinvent the wheel” each time I need a series of integers. With simple series the SQL Is not too bad. But more complicated series create much more complicated SQL. Now, many of my uses of SQL result in large SQL statements with can result in many uses of generate_series. To integrate multiple calls to the same series generation can be neatly encapsulated using the WITH construct, but even so it does add, to my way of thinking, unnecessary complicated. And complication usually means lots of errors and longer debugging.

In the end a generate_series function like above allows us to design and algorithm, code and test it and then use it many times without having to remember how to code an integer series every time we need it. This is part of good software engineering: the algorithm is “encapsulated” in a program unit that offers a stable interface. And interfaces are everything.

I hope that this is of use to someone.

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 [4]

Simon,
Neat. I’m tempted to do the same thing for SQL Server since its a pattern I use often especially for things that don’t lend themselves to standard SQL constructs like figuring out length of stays for homeless and hospitalization for claims analysis. I’m just not sure what the performance will be like.

In general I guess the size of the sets I generally use it for shouldn’t impact performance much.

Regina · 11 November 2008, 14:47 · #

Regina,

Thanks for commenting: I am a bit fan of your work on "PostGIS":http://postgis.refractions.net.

I have risen to the challenge and ported my version of generate_series to SQL Server 2008 T-SQL. I have tested it and it appears to work correctly.

DROP FUNCTION [generate_series]
GO
CREATE FUNCTION [generate_series] ( @p_start INT, @p_end INT, @p_step INT=1 )
RETURNS @Integers TABLE ( [IntValue] INT )
AS
BEGIN
    DECLARE @v_i                 INT;
    SET @v_i = CASE WHEN @p_start IS NULL THEN 1 ELSE @p_start END;
    DECLARE @v_step              INT;
    SET @v_step  = CASE WHEN @p_step IS NULL OR @p_step = 0 THEN 1 ELSE @p_step END;
    DECLARE @v_terminating_value INT;
    SET @v_terminating_value =  @p_start + CONVERT(INT,ABS(@p_start-@p_end) / ABS(@v_step) ) * @v_step;

     -- Check for impossible combinations
     IF NOT ( ( @p_start > @p_end AND SIGN(@p_step) = 1 )
              OR
              ( @p_start < @p_end AND SIGN(@p_step) = -1 )) 
     BEGIN
       WHILE ( 1 = 1 )
       BEGIN
           INSERT INTO @Integers ( [IntValue] ) VALUES ( @v_i )
           IF ( @v_i = @v_terminating_value )
              BREAK
           SET @v_i = @v_i + @v_step;
       END;
     END;
    RETURN
END
GO
SELECT g.IntValue
  FROM [generate_series] ( 100, 500, 10 ) g;
REM Unlike stored procedures, User Defined Functions (UDFs) require that all parameters 
REM be specified when calling them, even if default values for those parameters are declared. 
REM So, if we want to use a parameter's default value, one must use the DEFAULT T-SQL keyword 
REM instead of a parameter value. In this situation, this rather defeats the purpose of 
REM having a default parameter as it is easier to type 1 than DEFAULT!!!
REM
SELECT g.IntValue as generate_series 
  FROM generate_series(1,5,DEFAULT) g;
SELECT g.IntValue as generate_series 
  FROM generate_series(2,4,1) g;
SELECT g.IntValue as generate_series 
  FROM generate_series(5,1,-2) g;
SELECT g.IntValue as generate_series 
 FROM generate_series(4,3,1) g;
SELECT g.IntValue as generate_series 
  FROM generate_series(-4,-1,1) g;
SELECT convert(varchar(20),GETDATE() + sa.IntValue,112) as dates 
  FROM generate_series(0,14,7) sa;
I hope this is useful. Let me know if you want me to look at a version of the "Integers()" function and how to use it in ordinary SQL.

regards
Simon

Simon Greener · 13 November 2008, 22:59 · #

I appreciate the work done here. But my requirement little different than this. can i get a function which generate the series between 2 numbers without using TABLE.

Thanks in advance

— Jagadeesha · 1 February 2016, 20:27 · #

Jagadeesha,
The short answer is no.
It is either a table function or a hierarchical query.
Unless you provide some SQL to encapsulate your idea I can’t help.
Simon

— Simon Greener · 2 February 2016, 07:22 · #