--DO NOT MODIFY THIS FILE, IT IS GENERATED AUTOMATICALLY FROM SOURCES -- Complain if script is sourced in psql, rather than via CREATE EXTENSION \echo Use "CREATE EXTENSION crankshaft" to load this file. \quit -- Version number of the extension release CREATE OR REPLACE FUNCTION cdb_crankshaft_version() RETURNS text AS $$ SELECT '0.0.3'::text; $$ language 'sql' STABLE STRICT; -- Internal identifier of the installed extension instence -- e.g. 'dev' for current development version CREATE OR REPLACE FUNCTION _cdb_crankshaft_internal_version() RETURNS text AS $$ SELECT installed_version FROM pg_available_extensions where name='crankshaft' and pg_available_extensions IS NOT NULL; $$ language 'sql' STABLE STRICT; -- Internal function. -- Set the seeds of the RNGs (Random Number Generators) -- used internally. CREATE OR REPLACE FUNCTION _cdb_random_seeds (seed_value INTEGER) RETURNS VOID AS $$ from crankshaft import random_seeds random_seeds.set_random_seeds(seed_value) $$ LANGUAGE plpythonu; -- Moran's I Global Measure (public-facing) CREATE OR REPLACE FUNCTION CDB_AreasOfInterestGlobal( subquery TEXT, column_name TEXT, w_type TEXT DEFAULT 'knn', num_ngbrs INT DEFAULT 5, permutations INT DEFAULT 99, geom_col TEXT DEFAULT 'the_geom', id_col TEXT DEFAULT 'cartodb_id') RETURNS TABLE (moran NUMERIC, significance NUMERIC) AS $$ from crankshaft.clustering import moran_local # TODO: use named parameters or a dictionary return moran(subquery, column_name, w_type, num_ngbrs, permutations, geom_col, id_col) $$ LANGUAGE plpythonu; -- Moran's I Local (internal function) CREATE OR REPLACE FUNCTION _CDB_AreasOfInterestLocal( subquery TEXT, column_name TEXT, w_type TEXT, num_ngbrs INT, permutations INT, geom_col TEXT, id_col TEXT) RETURNS TABLE (moran NUMERIC, quads TEXT, significance NUMERIC, rowid INT, vals NUMERIC) AS $$ from crankshaft.clustering import moran_local # TODO: use named parameters or a dictionary return moran_local(subquery, column_name, w_type, num_ngbrs, permutations, geom_col, id_col) $$ LANGUAGE plpythonu; -- Moran's I Local (public-facing function) CREATE OR REPLACE FUNCTION CDB_AreasOfInterestLocal( subquery TEXT, column_name TEXT, w_type TEXT DEFAULT 'knn', num_ngbrs INT DEFAULT 5, permutations INT DEFAULT 99, geom_col TEXT DEFAULT 'the_geom', id_col TEXT DEFAULT 'cartodb_id') RETURNS TABLE (moran NUMERIC, quads TEXT, significance NUMERIC, rowid INT, vals NUMERIC) AS $$ SELECT moran, quads, significance, rowid, vals FROM cdb_crankshaft._CDB_AreasOfInterestLocal(subquery, column_name, w_type, num_ngbrs, permutations, geom_col, id_col); $$ LANGUAGE SQL; -- Moran's I only for HH and HL (public-facing function) CREATE OR REPLACE FUNCTION CDB_GetSpatialHotspots( subquery TEXT, column_name TEXT, w_type TEXT DEFAULT 'knn', num_ngbrs INT DEFAULT 5, permutations INT DEFAULT 99, geom_col TEXT DEFAULT 'the_geom', id_col TEXT DEFAULT 'cartodb_id') RETURNS TABLE (moran NUMERIC, quads TEXT, significance NUMERIC, rowid INT, vals NUMERIC) AS $$ SELECT moran, quads, significance, rowid, vals FROM cdb_crankshaft._CDB_AreasOfInterestLocal(subquery, column_name, w_type, num_ngbrs, permutations, geom_col, id_col) WHERE quads IN ('HH', 'HL'); $$ LANGUAGE SQL; -- Moran's I only for LL and LH (public-facing function) CREATE OR REPLACE FUNCTION CDB_GetSpatialColdspots( subquery TEXT, attr TEXT, w_type TEXT DEFAULT 'knn', num_ngbrs INT DEFAULT 5, permutations INT DEFAULT 99, geom_col TEXT DEFAULT 'the_geom', id_col TEXT DEFAULT 'cartodb_id') RETURNS TABLE (moran NUMERIC, quads TEXT, significance NUMERIC, rowid INT, vals NUMERIC) AS $$ SELECT moran, quads, significance, rowid, vals FROM cdb_crankshaft._CDB_AreasOfInterestLocal(subquery, attr, w_type, num_ngbrs, permutations, geom_col, id_col) WHERE quads IN ('LL', 'LH'); $$ LANGUAGE SQL; -- Moran's I only for LH and HL (public-facing function) CREATE OR REPLACE FUNCTION CDB_GetSpatialOutliers( subquery TEXT, attr TEXT, w_type TEXT DEFAULT 'knn', num_ngbrs INT DEFAULT 5, permutations INT DEFAULT 99, geom_col TEXT DEFAULT 'the_geom', id_col TEXT DEFAULT 'cartodb_id') RETURNS TABLE (moran NUMERIC, quads TEXT, significance NUMERIC, rowid INT, vals NUMERIC) AS $$ SELECT moran, quads, significance, rowid, vals FROM cdb_crankshaft._CDB_AreasOfInterestLocal(subquery, attr, w_type, num_ngbrs, permutations, geom_col, id_col) WHERE quads IN ('HL', 'LH'); $$ LANGUAGE SQL; -- Moran's I Global Rate (public-facing function) CREATE OR REPLACE FUNCTION CDB_AreasOfInterestGlobalRate( subquery TEXT, numerator TEXT, denominator TEXT, w_type TEXT DEFAULT 'knn', num_ngbrs INT DEFAULT 5, permutations INT DEFAULT 99, geom_col TEXT DEFAULT 'the_geom', id_col TEXT DEFAULT 'cartodb_id') RETURNS TABLE (moran FLOAT, significance FLOAT) AS $$ from crankshaft.clustering import moran_local # TODO: use named parameters or a dictionary return moran_rate(subquery, numerator, denominator, w_type, num_ngbrs, permutations, geom_col, id_col) $$ LANGUAGE plpythonu; -- Moran's I Local Rate (internal function) CREATE OR REPLACE FUNCTION _CDB_AreasOfInterestLocalRate( subquery TEXT, numerator TEXT, denominator TEXT, w_type TEXT, num_ngbrs INT, permutations INT, geom_col TEXT, id_col TEXT) RETURNS TABLE(moran NUMERIC, quads TEXT, significance NUMERIC, rowid INT, vals NUMERIC) AS $$ from crankshaft.clustering import moran_local_rate # TODO: use named parameters or a dictionary return moran_local_rate(subquery, numerator, denominator, w_type, num_ngbrs, permutations, geom_col, id_col) $$ LANGUAGE plpythonu; -- Moran's I Local Rate (public-facing function) CREATE OR REPLACE FUNCTION CDB_AreasOfInterestLocalRate( subquery TEXT, numerator TEXT, denominator TEXT, w_type TEXT DEFAULT 'knn', num_ngbrs INT DEFAULT 5, permutations INT DEFAULT 99, geom_col TEXT DEFAULT 'the_geom', id_col TEXT DEFAULT 'cartodb_id') RETURNS TABLE(moran NUMERIC, quads TEXT, significance NUMERIC, rowid INT, vals NUMERIC) AS $$ SELECT moran, quads, significance, rowid, vals FROM cdb_crankshaft._CDB_AreasOfInterestLocalRate(subquery, numerator, denominator, w_type, num_ngbrs, permutations, geom_col, id_col); $$ LANGUAGE SQL; -- Moran's I Local Rate only for HH and HL (public-facing function) CREATE OR REPLACE FUNCTION CDB_GetSpatialHotspotsRate( subquery TEXT, numerator TEXT, denominator TEXT, w_type TEXT DEFAULT 'knn', num_ngbrs INT DEFAULT 5, permutations INT DEFAULT 99, geom_col TEXT DEFAULT 'the_geom', id_col TEXT DEFAULT 'cartodb_id') RETURNS TABLE(moran NUMERIC, quads TEXT, significance NUMERIC, rowid INT, vals NUMERIC) AS $$ SELECT moran, quads, significance, rowid, vals FROM cdb_crankshaft._CDB_AreasOfInterestLocalRate(subquery, numerator, denominator, w_type, num_ngbrs, permutations, geom_col, id_col) WHERE quads IN ('HH', 'HL'); $$ LANGUAGE SQL; -- Moran's I Local Rate only for LL and LH (public-facing function) CREATE OR REPLACE FUNCTION CDB_GetSpatialColdspotsRate( subquery TEXT, numerator TEXT, denominator TEXT, w_type TEXT DEFAULT 'knn', num_ngbrs INT DEFAULT 5, permutations INT DEFAULT 99, geom_col TEXT DEFAULT 'the_geom', id_col TEXT DEFAULT 'cartodb_id') RETURNS TABLE(moran NUMERIC, quads TEXT, significance NUMERIC, rowid INT, vals NUMERIC) AS $$ SELECT moran, quads, significance, rowid, vals FROM cdb_crankshaft._CDB_AreasOfInterestLocalRate(subquery, numerator, denominator, w_type, num_ngbrs, permutations, geom_col, id_col) WHERE quads IN ('LL', 'LH'); $$ LANGUAGE SQL; -- Moran's I Local Rate only for LH and HL (public-facing function) CREATE OR REPLACE FUNCTION CDB_GetSpatialOutliersRate( subquery TEXT, numerator TEXT, denominator TEXT, w_type TEXT DEFAULT 'knn', num_ngbrs INT DEFAULT 5, permutations INT DEFAULT 99, geom_col TEXT DEFAULT 'the_geom', id_col TEXT DEFAULT 'cartodb_id') RETURNS TABLE(moran NUMERIC, quads TEXT, significance NUMERIC, rowid INT, vals NUMERIC) AS $$ SELECT moran, quads, significance, rowid, vals FROM cdb_crankshaft._CDB_AreasOfInterestLocalRate(subquery, numerator, denominator, w_type, num_ngbrs, permutations, geom_col, id_col) WHERE quads IN ('HL', 'LH'); $$ LANGUAGE SQL; CREATE OR REPLACE FUNCTION CDB_KMeans(query text, no_clusters integer,no_init integer default 20) RETURNS table (cartodb_id integer, cluster_no integer) as $$ from crankshaft.clustering import kmeans return kmeans(query,no_clusters,no_init) $$ language plpythonu; CREATE OR REPLACE FUNCTION CDB_WeightedMeanS(state Numeric[],the_geom GEOMETRY(Point, 4326), weight NUMERIC) RETURNS Numeric[] AS $$ DECLARE newX NUMERIC; newY NUMERIC; newW NUMERIC; BEGIN IF weight IS NULL OR the_geom IS NULL THEN newX = state[1]; newY = state[2]; newW = state[3]; ELSE newX = state[1] + ST_X(the_geom)*weight; newY = state[2] + ST_Y(the_geom)*weight; newW = state[3] + weight; END IF; RETURN Array[newX,newY,newW]; END $$ LANGUAGE plpgsql; CREATE OR REPLACE FUNCTION CDB_WeightedMeanF(state Numeric[]) RETURNS GEOMETRY AS $$ BEGIN IF state[3] = 0 THEN RETURN ST_SetSRID(ST_MakePoint(state[1],state[2]), 4326); ELSE RETURN ST_SETSRID(ST_MakePoint(state[1]/state[3], state[2]/state[3]),4326); END IF; END $$ LANGUAGE plpgsql; CREATE AGGREGATE CDB_WeightedMean(geometry(Point, 4326), NUMERIC)( SFUNC = CDB_WeightedMeanS, FINALFUNC = CDB_WeightedMeanF, STYPE = Numeric[], INITCOND = "{0.0,0.0,0.0}" ); -- Function by Stuart Lynn for a simple interpolation of a value -- from a polygon table over an arbitrary polygon -- (weighted by the area proportion overlapped) -- Aereal weighting is a very simple form of aereal interpolation. -- -- Parameters: -- * geom a Polygon geometry which defines the area where a value will be -- estimated as the area-weighted sum of a given table/column -- * target_table_name table name of the table that provides the values -- * target_column column name of the column that provides the values -- * schema_name optional parameter to defina the schema the target table -- belongs to, which is necessary if its not in the search_path. -- Note that target_table_name should never include the schema in it. -- Return value: -- Aereal-weighted interpolation of the column values over the geometry CREATE OR REPLACE FUNCTION cdb_overlap_sum(geom geometry, target_table_name text, target_column text, schema_name text DEFAULT NULL) RETURNS numeric AS $$ DECLARE result numeric; qualified_name text; BEGIN IF schema_name IS NULL THEN qualified_name := Format('%I', target_table_name); ELSE qualified_name := Format('%I.%s', schema_name, target_table_name); END IF; EXECUTE Format(' SELECT sum(%I*ST_Area(St_Intersection($1, a.the_geom))/ST_Area(a.the_geom)) FROM %s AS a WHERE $1 && a.the_geom ', target_column, qualified_name) USING geom INTO result; RETURN result; END; $$ LANGUAGE plpgsql; -- -- Creates N points randomly distributed arround the polygon -- -- @param g - the geometry to be turned in to points -- -- @param no_points - the number of points to generate -- -- @params max_iter_per_point - the function generates points in the polygon's bounding box -- and discards points which don't lie in the polygon. max_iter_per_point specifies how many -- misses per point the funciton accepts before giving up. -- -- Returns: Multipoint with the requested points CREATE OR REPLACE FUNCTION cdb_dot_density(geom geometry , no_points Integer, max_iter_per_point Integer DEFAULT 1000) RETURNS GEOMETRY AS $$ DECLARE extent GEOMETRY; test_point Geometry; width NUMERIC; height NUMERIC; x0 NUMERIC; y0 NUMERIC; xp NUMERIC; yp NUMERIC; no_left INTEGER; remaining_iterations INTEGER; points GEOMETRY[]; bbox_line GEOMETRY; intersection_line GEOMETRY; BEGIN extent := ST_Envelope(geom); width := ST_XMax(extent) - ST_XMIN(extent); height := ST_YMax(extent) - ST_YMIN(extent); x0 := ST_XMin(extent); y0 := ST_YMin(extent); no_left := no_points; LOOP if(no_left=0) THEN EXIT; END IF; yp = y0 + height*random(); bbox_line = ST_MakeLine( ST_SetSRID(ST_MakePoint(yp, x0),4326), ST_SetSRID(ST_MakePoint(yp, x0+width),4326) ); intersection_line = ST_Intersection(bbox_line,geom); test_point = ST_LineInterpolatePoint(st_makeline(st_linemerge(intersection_line)),random()); points := points || test_point; no_left = no_left - 1 ; END LOOP; RETURN ST_Collect(points); END; $$ LANGUAGE plpgsql VOLATILE; -- Make sure by default there are no permissions for publicuser -- NOTE: this happens at extension creation time, as part of an implicit transaction. -- REVOKE ALL PRIVILEGES ON SCHEMA cdb_crankshaft FROM PUBLIC, publicuser CASCADE; -- Grant permissions on the schema to publicuser (but just the schema) GRANT USAGE ON SCHEMA cdb_crankshaft TO publicuser; -- Revoke execute permissions on all functions in the schema by default -- REVOKE EXECUTE ON ALL FUNCTIONS IN SCHEMA cdb_crankshaft FROM PUBLIC, publicuser;