Skip to content

Commit

Permalink
rewritten objectclass_id_to_table_name function and added new convers…
Browse files Browse the repository at this point in the history
…ion function table_name_to_objectclass_ids
  • Loading branch information
FxKu committed Mar 25, 2018
1 parent cba1c9c commit 9561d47
Show file tree
Hide file tree
Showing 2 changed files with 79 additions and 158 deletions.
117 changes: 37 additions & 80 deletions Oracle/SQLScripts/PL_SQL/CITYDB_PKG/UTIL/UTIL.sql
Original file line number Diff line number Diff line change
Expand Up @@ -101,6 +101,7 @@ AS
FUNCTION id_array2string(ids ID_ARRAY, delim VARCHAR2 := ',') RETURN VARCHAR2;
FUNCTION get_id_array_size(id_arr ID_ARRAY) RETURN NUMBER;
FUNCTION objectclass_id_to_table_name(class_id NUMBER) RETURN VARCHAR2;
FUNCTION table_name_to_objectclass_ids(table_name VARCHAR2) RETURN ID_ARRAY;
FUNCTION construct_solid(geom_root_id NUMBER) RETURN SDO_GEOMETRY;
FUNCTION to_2d(geom MDSYS.SDO_GEOMETRY, srid NUMBER) RETURN MDSYS.SDO_GEOMETRY;
FUNCTION sdo2geojson3d(p_geometry in sdo_geometry, p_decimal_places in pls_integer default 2, p_compress_tags in pls_integer default 0, p_relative2mbr in pls_integer default 0) RETURN CLOB DETERMINISTIC;
Expand Down Expand Up @@ -537,89 +538,45 @@ AS
IS
table_name VARCHAR2(30) := '';
BEGIN
CASE
WHEN class_id = 4 THEN table_name := 'land_use';
WHEN class_id = 5 THEN table_name := 'generic_cityobject';
WHEN class_id = 7 THEN table_name := 'solitary_vegetat_object';
WHEN class_id = 8 THEN table_name := 'plant_cover';
WHEN class_id = 9 THEN table_name := 'waterbody';
WHEN class_id = 11 OR
class_id = 12 OR
class_id = 13 THEN table_name := 'waterboundary_surface';
WHEN class_id = 14 THEN table_name := 'relief_feature';
WHEN class_id = 16 OR
class_id = 17 OR
class_id = 18 OR
class_id = 19 THEN table_name := 'relief_component';
WHEN class_id = 21 THEN table_name := 'city_furniture';
WHEN class_id = 23 THEN table_name := 'cityobjectgroup';
WHEN class_id = 25 OR
class_id = 26 THEN table_name := 'building';
WHEN class_id = 27 OR
class_id = 28 THEN table_name := 'building_installation';
WHEN class_id = 30 OR
class_id = 31 OR
class_id = 32 OR
class_id = 33 OR
class_id = 34 OR
class_id = 35 OR
class_id = 36 OR
class_id = 60 OR
class_id = 61 THEN table_name := 'thematic_surface';
WHEN class_id = 38 OR
class_id = 39 THEN table_name := 'opening';
WHEN class_id = 40 THEN table_name := 'building_furniture';
WHEN class_id = 41 THEN table_name := 'room';
WHEN class_id = 43 OR
class_id = 44 OR
class_id = 45 OR
class_id = 46 THEN table_name := 'transportation_complex';
WHEN class_id = 47 OR
class_id = 48 THEN table_name := 'traffic_area';
WHEN class_id = 57 THEN table_name := 'citymodel';
WHEN class_id = 63 OR
class_id = 64 THEN table_name := 'bridge';
WHEN class_id = 65 OR
class_id = 66 THEN table_name := 'bridge_installation';
WHEN class_id = 68 OR
class_id = 69 OR
class_id = 70 OR
class_id = 71 OR
class_id = 72 OR
class_id = 73 OR
class_id = 74 OR
class_id = 75 OR
class_id = 76 THEN table_name := 'bridge_thematic_surface';
WHEN class_id = 78 OR
class_id = 79 THEN table_name := 'bridge_opening';
WHEN class_id = 80 THEN table_name := 'bridge_furniture';
WHEN class_id = 81 THEN table_name := 'bridge_room';
WHEN class_id = 82 THEN table_name := 'bridge_constr_element';
WHEN class_id = 84 OR
class_id = 85 THEN table_name := 'tunnel';
WHEN class_id = 86 OR
class_id = 87 THEN table_name := 'tunnel_installation';
WHEN class_id = 88 OR
class_id = 89 OR
class_id = 90 OR
class_id = 91 OR
class_id = 92 OR
class_id = 93 OR
class_id = 94 OR
class_id = 95 OR
class_id = 96 THEN table_name := 'tunnel_thematic_surface';
WHEN class_id = 99 OR
class_id = 100 THEN table_name := 'tunnel_opening';
WHEN class_id = 101 THEN table_name := 'tunnel_furniture';
WHEN class_id = 102 THEN table_name := 'tunnel_hollow_space';
ELSE
dbms_output.put_line('Table name unknown.');
NULL;
END CASE;
SELECT
tablename
INTO
table_name
FROM
objectclass
WHERE
id = class_id;

RETURN table_name;
END;



/*****************************************************************
* table_name_to_objectclass_ids
*
* @param table_name name of table
* @return ID_ARRAY array of objectclass_ids
******************************************************************/
FUNCTION table_name_to_objectclass_ids(table_name VARCHAR2) RETURN ID_ARRAY
IS
objclass_ids ID_ARRAY;
BEGIN
SELECT DISTINCT
id
BULK COLLECT INTO
objclass_ids
FROM
objectclass
START WITH
tablename = lower(table_name)
CONNECT BY PRIOR
id = superclass_id
ORDER BY
id;

RETURN objclass_ids;
END;


/*****************************************************************
* construct_solid
Expand Down
120 changes: 42 additions & 78 deletions PostgreSQL/SQLScripts/PL_pgSQL/CITYDB_PKG/UTIL/UTIL.sql
Original file line number Diff line number Diff line change
Expand Up @@ -53,6 +53,7 @@
* get_seq_values(seq_name TEXT, seq_count INTEGER) RETURNS SETOF INTEGER
* min(a NUMERIC, b NUMERIC) RETURNS NUMERIC
* objectclass_id_to_table_name(class_id INTEGER) RETURNS TEXT
* table_name_to_objectclass_ids(table_name TEXT) RETURNS INTEGER[]
* update_schema_constraints(on_delete_param TEXT DEFAULT 'CASCADE', schema_name TEXT DEFAULT 'citydb') RETURNS SETOF VOID
* update_table_constraint(fkey_name TEXT, table_name TEXT, column_name TEXT, ref_table TEXT, ref_column TEXT,
* delete_param TEXT, deferrable_param TEXT, schema_name TEXT DEFAULT 'citydb') RETURNS SETOF VOID
Expand Down Expand Up @@ -314,83 +315,46 @@ LANGUAGE sql STRICT;
******************************************************************/
CREATE OR REPLACE FUNCTION citydb_pkg.objectclass_id_to_table_name(class_id INTEGER) RETURNS TEXT AS
$$
SELECT CASE
WHEN $1 = 4 THEN 'land_use'
WHEN $1 = 5 THEN 'generic_cityobject'
WHEN $1 = 7 THEN 'solitary_vegetat_object'
WHEN $1 = 8 THEN 'plant_cover'
WHEN $1 = 9 THEN 'waterbody'
WHEN $1 = 11 OR
$1 = 12 OR
$1 = 13 THEN 'waterboundary_surface'
WHEN $1 = 14 THEN 'relief_feature'
WHEN $1 = 16 OR
$1 = 17 OR
$1 = 18 OR
$1 = 19 THEN 'relief_component'
WHEN $1 = 21 THEN 'city_furniture'
WHEN $1 = 23 THEN 'cityobjectgroup'
WHEN $1 = 25 OR
$1 = 26 THEN 'building'
WHEN $1 = 27 OR
$1 = 28 THEN 'building_installation'
WHEN $1 = 30 OR
$1 = 31 OR
$1 = 32 OR
$1 = 33 OR
$1 = 34 OR
$1 = 35 OR
$1 = 36 OR
$1 = 60 OR
$1 = 61 THEN 'thematic_surface'
WHEN $1 = 38 OR
$1 = 39 THEN 'opening'
WHEN $1 = 40 THEN 'building_furniture'
WHEN $1 = 41 THEN 'room'
WHEN $1 = 43 OR
$1 = 44 OR
$1 = 45 OR
$1 = 46 THEN 'transportation_complex'
WHEN $1 = 47 OR
$1 = 48 THEN 'traffic_area'
WHEN $1 = 57 THEN 'citymodel'
WHEN $1 = 63 OR
$1 = 64 THEN 'bridge'
WHEN $1 = 65 OR
$1 = 66 THEN 'bridge_installation'
WHEN $1 = 68 OR
$1 = 69 OR
$1 = 70 OR
$1 = 71 OR
$1 = 72 OR
$1 = 73 OR
$1 = 74 OR
$1 = 75 OR
$1 = 76 THEN 'bridge_thematic_surface'
WHEN $1 = 78 OR
$1 = 79 THEN 'bridge_opening'
WHEN $1 = 80 THEN 'bridge_furniture'
WHEN $1 = 81 THEN 'bridge_room'
WHEN $1 = 82 THEN 'bridge_constr_element'
WHEN $1 = 84 OR
$1 = 85 THEN 'tunnel'
WHEN $1 = 86 OR
$1 = 87 THEN 'tunnel_installation'
WHEN $1 = 88 OR
$1 = 89 OR
$1 = 90 OR
$1 = 91 OR
$1 = 92 OR
$1 = 93 OR
$1 = 94 OR
$1 = 95 OR
$1 = 96 THEN 'tunnel_thematic_surface'
WHEN $1 = 99 OR
$1 = 100 THEN 'tunnel_opening'
WHEN $1 = 101 THEN 'tunnel_furniture'
WHEN $1 = 102 THEN 'tunnel_hollow_space'
ELSE
'Unknown table'
END;
SELECT
tablename
FROM
objectclass
WHERE
id = $1;
$$
LANGUAGE sql IMMUTABLE STRICT;


/*****************************************************************
* table_name_to_objectclass_ids
*
* @param table_name name of table
*
* @RETURN INT[] array of objectclass_ids
******************************************************************/
CREATE OR REPLACE FUNCTION citydb_pkg.table_name_to_objectclass_ids(table_name TEXT) RETURNS INTEGER[] AS
$$
WITH RECURSIVE objectclass_tree (id, superclass_id) AS (
SELECT
id,
superclass_id
FROM
objectclass
WHERE
tablename = lower($1)
UNION ALL
SELECT
o.id,
o.superclass_id
FROM
objectclass o,
objectclass_tree t
WHERE
o.superclass_id = t.id
)
SELECT
array_agg(DISTINCT id ORDER BY id)
FROM
objectclass_tree;
$$
LANGUAGE sql IMMUTABLE STRICT;

0 comments on commit 9561d47

Please sign in to comment.