-- Complain if script is sourced in psql, rather than via CREATE EXTENSION \echo Use "CREATE EXTENSION cdb_geocoder_client" to load this file. \quit -- -- Geocoder server connection config -- -- The purpose of this function is provide to the PL/Proxy functions -- the connection string needed to connect with the server CREATE OR REPLACE FUNCTION cdb_geocoder_client._server_conn_str() RETURNS text AS $$ DECLARE db_connection_str text; BEGIN SELECT cartodb.cdb_conf_getconf('geocoder_server_config')->'connection_str' INTO db_connection_str; SELECT trim(both '"' FROM db_connection_str) INTO db_connection_str; RETURN db_connection_str; END; $$ LANGUAGE 'plpgsql';CREATE TYPE cdb_geocoder_client._entity_config AS ( username text, organization_name text ); -- -- Get entity config function -- -- The purpose of this function is to retrieve the username and organization name from -- a) schema where he/her is the owner in case is an organization user -- b) entity_name from the cdb_conf database in case is a non organization user CREATE OR REPLACE FUNCTION cdb_geocoder_client._cdb_entity_config() RETURNS record AS $$ DECLARE result cdb_geocoder_client._entity_config; is_organization boolean; username text; organization_name text; BEGIN SELECT cartodb.cdb_conf_getconf('user_config')->'is_organization' INTO is_organization; IF is_organization IS NULL THEN RAISE EXCEPTION 'User must have user configuration in the config table'; ELSIF is_organization = TRUE THEN SELECT nspname FROM pg_namespace s LEFT JOIN pg_roles r ON s.nspowner = r.oid WHERE r.rolname = session_user INTO username; SELECT cartodb.cdb_conf_getconf('user_config')->'entity_name' INTO organization_name; ELSE SELECT cartodb.cdb_conf_getconf('user_config')->'entity_name' INTO username; organization_name = NULL; END IF; result.username = username; result.organization_name = organization_name; RETURN result; END; $$ LANGUAGE 'plpgsql' SECURITY DEFINER;-- -- Public geocoder API function -- -- These are the only ones with permissions to publicuser role -- and should also be the only ones with SECURITY DEFINER CREATE OR REPLACE FUNCTION cdb_geocoder_client.cdb_geocode_admin0_polygon (country_name text) RETURNS Geometry AS $$ DECLARE ret Geometry; username text; orgname text; BEGIN IF session_user = 'publicuser' OR session_user ~ 'cartodb_publicuser_*' THEN RAISE EXCEPTION 'The api_key must be provided'; END IF; SELECT u, o INTO username, orgname FROM cdb_geocoder_client._cdb_entity_config() AS (u text, o text); -- JSON value stored "" is taken as literal IF username IS NULL OR username = '' OR username = '""' THEN RAISE EXCEPTION 'Username is a mandatory argument, check it out'; END IF; SELECT cdb_geocoder_client._cdb_geocode_admin0_polygon(username, orgname, country_name) INTO ret; RETURN ret; END; $$ LANGUAGE 'plpgsql' SECURITY DEFINER; -- -- Public geocoder API function -- -- These are the only ones with permissions to publicuser role -- and should also be the only ones with SECURITY DEFINER CREATE OR REPLACE FUNCTION cdb_geocoder_client.cdb_geocode_admin1_polygon (admin1_name text) RETURNS Geometry AS $$ DECLARE ret Geometry; username text; orgname text; BEGIN IF session_user = 'publicuser' OR session_user ~ 'cartodb_publicuser_*' THEN RAISE EXCEPTION 'The api_key must be provided'; END IF; SELECT u, o INTO username, orgname FROM cdb_geocoder_client._cdb_entity_config() AS (u text, o text); -- JSON value stored "" is taken as literal IF username IS NULL OR username = '' OR username = '""' THEN RAISE EXCEPTION 'Username is a mandatory argument, check it out'; END IF; SELECT cdb_geocoder_client._cdb_geocode_admin1_polygon(username, orgname, admin1_name) INTO ret; RETURN ret; END; $$ LANGUAGE 'plpgsql' SECURITY DEFINER; -- -- Public geocoder API function -- -- These are the only ones with permissions to publicuser role -- and should also be the only ones with SECURITY DEFINER CREATE OR REPLACE FUNCTION cdb_geocoder_client.cdb_geocode_admin1_polygon (admin1_name text, country_name text) RETURNS Geometry AS $$ DECLARE ret Geometry; username text; orgname text; BEGIN IF session_user = 'publicuser' OR session_user ~ 'cartodb_publicuser_*' THEN RAISE EXCEPTION 'The api_key must be provided'; END IF; SELECT u, o INTO username, orgname FROM cdb_geocoder_client._cdb_entity_config() AS (u text, o text); -- JSON value stored "" is taken as literal IF username IS NULL OR username = '' OR username = '""' THEN RAISE EXCEPTION 'Username is a mandatory argument, check it out'; END IF; SELECT cdb_geocoder_client._cdb_geocode_admin1_polygon(username, orgname, admin1_name, country_name) INTO ret; RETURN ret; END; $$ LANGUAGE 'plpgsql' SECURITY DEFINER; -- -- Public geocoder API function -- -- These are the only ones with permissions to publicuser role -- and should also be the only ones with SECURITY DEFINER CREATE OR REPLACE FUNCTION cdb_geocoder_client.cdb_geocode_namedplace_point (city_name text) RETURNS Geometry AS $$ DECLARE ret Geometry; username text; orgname text; BEGIN IF session_user = 'publicuser' OR session_user ~ 'cartodb_publicuser_*' THEN RAISE EXCEPTION 'The api_key must be provided'; END IF; SELECT u, o INTO username, orgname FROM cdb_geocoder_client._cdb_entity_config() AS (u text, o text); -- JSON value stored "" is taken as literal IF username IS NULL OR username = '' OR username = '""' THEN RAISE EXCEPTION 'Username is a mandatory argument, check it out'; END IF; SELECT cdb_geocoder_client._cdb_geocode_namedplace_point(username, orgname, city_name) INTO ret; RETURN ret; END; $$ LANGUAGE 'plpgsql' SECURITY DEFINER; -- -- Public geocoder API function -- -- These are the only ones with permissions to publicuser role -- and should also be the only ones with SECURITY DEFINER CREATE OR REPLACE FUNCTION cdb_geocoder_client.cdb_geocode_namedplace_point (city_name text, country_name text) RETURNS Geometry AS $$ DECLARE ret Geometry; username text; orgname text; BEGIN IF session_user = 'publicuser' OR session_user ~ 'cartodb_publicuser_*' THEN RAISE EXCEPTION 'The api_key must be provided'; END IF; SELECT u, o INTO username, orgname FROM cdb_geocoder_client._cdb_entity_config() AS (u text, o text); -- JSON value stored "" is taken as literal IF username IS NULL OR username = '' OR username = '""' THEN RAISE EXCEPTION 'Username is a mandatory argument, check it out'; END IF; SELECT cdb_geocoder_client._cdb_geocode_namedplace_point(username, orgname, city_name, country_name) INTO ret; RETURN ret; END; $$ LANGUAGE 'plpgsql' SECURITY DEFINER; -- -- Public geocoder API function -- -- These are the only ones with permissions to publicuser role -- and should also be the only ones with SECURITY DEFINER CREATE OR REPLACE FUNCTION cdb_geocoder_client.cdb_geocode_namedplace_point (city_name text, admin1_name text, country_name text) RETURNS Geometry AS $$ DECLARE ret Geometry; username text; orgname text; BEGIN IF session_user = 'publicuser' OR session_user ~ 'cartodb_publicuser_*' THEN RAISE EXCEPTION 'The api_key must be provided'; END IF; SELECT u, o INTO username, orgname FROM cdb_geocoder_client._cdb_entity_config() AS (u text, o text); -- JSON value stored "" is taken as literal IF username IS NULL OR username = '' OR username = '""' THEN RAISE EXCEPTION 'Username is a mandatory argument, check it out'; END IF; SELECT cdb_geocoder_client._cdb_geocode_namedplace_point(username, orgname, city_name, admin1_name, country_name) INTO ret; RETURN ret; END; $$ LANGUAGE 'plpgsql' SECURITY DEFINER; -- -- Public geocoder API function -- -- These are the only ones with permissions to publicuser role -- and should also be the only ones with SECURITY DEFINER CREATE OR REPLACE FUNCTION cdb_geocoder_client.cdb_geocode_postalcode_polygon (postal_code text, country_name text) RETURNS Geometry AS $$ DECLARE ret Geometry; username text; orgname text; BEGIN IF session_user = 'publicuser' OR session_user ~ 'cartodb_publicuser_*' THEN RAISE EXCEPTION 'The api_key must be provided'; END IF; SELECT u, o INTO username, orgname FROM cdb_geocoder_client._cdb_entity_config() AS (u text, o text); -- JSON value stored "" is taken as literal IF username IS NULL OR username = '' OR username = '""' THEN RAISE EXCEPTION 'Username is a mandatory argument, check it out'; END IF; SELECT cdb_geocoder_client._cdb_geocode_postalcode_polygon(username, orgname, postal_code, country_name) INTO ret; RETURN ret; END; $$ LANGUAGE 'plpgsql' SECURITY DEFINER; -- -- Public geocoder API function -- -- These are the only ones with permissions to publicuser role -- and should also be the only ones with SECURITY DEFINER CREATE OR REPLACE FUNCTION cdb_geocoder_client.cdb_geocode_postalcode_point (postal_code text, country_name text) RETURNS Geometry AS $$ DECLARE ret Geometry; username text; orgname text; BEGIN IF session_user = 'publicuser' OR session_user ~ 'cartodb_publicuser_*' THEN RAISE EXCEPTION 'The api_key must be provided'; END IF; SELECT u, o INTO username, orgname FROM cdb_geocoder_client._cdb_entity_config() AS (u text, o text); -- JSON value stored "" is taken as literal IF username IS NULL OR username = '' OR username = '""' THEN RAISE EXCEPTION 'Username is a mandatory argument, check it out'; END IF; SELECT cdb_geocoder_client._cdb_geocode_postalcode_point(username, orgname, postal_code, country_name) INTO ret; RETURN ret; END; $$ LANGUAGE 'plpgsql' SECURITY DEFINER; -- -- Public geocoder API function -- -- These are the only ones with permissions to publicuser role -- and should also be the only ones with SECURITY DEFINER CREATE OR REPLACE FUNCTION cdb_geocoder_client.cdb_geocode_ipaddress_point (ip_address text) RETURNS Geometry AS $$ DECLARE ret Geometry; username text; orgname text; BEGIN IF session_user = 'publicuser' OR session_user ~ 'cartodb_publicuser_*' THEN RAISE EXCEPTION 'The api_key must be provided'; END IF; SELECT u, o INTO username, orgname FROM cdb_geocoder_client._cdb_entity_config() AS (u text, o text); -- JSON value stored "" is taken as literal IF username IS NULL OR username = '' OR username = '""' THEN RAISE EXCEPTION 'Username is a mandatory argument, check it out'; END IF; SELECT cdb_geocoder_client._cdb_geocode_ipaddress_point(username, orgname, ip_address) INTO ret; RETURN ret; END; $$ LANGUAGE 'plpgsql' SECURITY DEFINER; CREATE OR REPLACE FUNCTION cdb_geocoder_client._cdb_geocode_admin0_polygon (username text, organization_name text, country_name text) RETURNS Geometry AS $$ CONNECT cdb_geocoder_client._server_conn_str(); SELECT cdb_geocoder_server.cdb_geocode_admin0_polygon (username, organization_name, country_name); $$ LANGUAGE plproxy; CREATE OR REPLACE FUNCTION cdb_geocoder_client._cdb_geocode_admin1_polygon (username text, organization_name text, admin1_name text) RETURNS Geometry AS $$ CONNECT cdb_geocoder_client._server_conn_str(); SELECT cdb_geocoder_server.cdb_geocode_admin1_polygon (username, organization_name, admin1_name); $$ LANGUAGE plproxy; CREATE OR REPLACE FUNCTION cdb_geocoder_client._cdb_geocode_admin1_polygon (username text, organization_name text, admin1_name text, country_name text) RETURNS Geometry AS $$ CONNECT cdb_geocoder_client._server_conn_str(); SELECT cdb_geocoder_server.cdb_geocode_admin1_polygon (username, organization_name, admin1_name, country_name); $$ LANGUAGE plproxy; CREATE OR REPLACE FUNCTION cdb_geocoder_client._cdb_geocode_namedplace_point (username text, organization_name text, city_name text) RETURNS Geometry AS $$ CONNECT cdb_geocoder_client._server_conn_str(); SELECT cdb_geocoder_server.cdb_geocode_namedplace_point (username, organization_name, city_name); $$ LANGUAGE plproxy; CREATE OR REPLACE FUNCTION cdb_geocoder_client._cdb_geocode_namedplace_point (username text, organization_name text, city_name text, country_name text) RETURNS Geometry AS $$ CONNECT cdb_geocoder_client._server_conn_str(); SELECT cdb_geocoder_server.cdb_geocode_namedplace_point (username, organization_name, city_name, country_name); $$ LANGUAGE plproxy; CREATE OR REPLACE FUNCTION cdb_geocoder_client._cdb_geocode_namedplace_point (username text, organization_name text, city_name text, admin1_name text, country_name text) RETURNS Geometry AS $$ CONNECT cdb_geocoder_client._server_conn_str(); SELECT cdb_geocoder_server.cdb_geocode_namedplace_point (username, organization_name, city_name, admin1_name, country_name); $$ LANGUAGE plproxy; CREATE OR REPLACE FUNCTION cdb_geocoder_client._cdb_geocode_postalcode_polygon (username text, organization_name text, postal_code text, country_name text) RETURNS Geometry AS $$ CONNECT cdb_geocoder_client._server_conn_str(); SELECT cdb_geocoder_server.cdb_geocode_postalcode_polygon (username, organization_name, postal_code, country_name); $$ LANGUAGE plproxy; CREATE OR REPLACE FUNCTION cdb_geocoder_client._cdb_geocode_postalcode_point (username text, organization_name text, postal_code text, country_name text) RETURNS Geometry AS $$ CONNECT cdb_geocoder_client._server_conn_str(); SELECT cdb_geocoder_server.cdb_geocode_postalcode_point (username, organization_name, postal_code, country_name); $$ LANGUAGE plproxy; CREATE OR REPLACE FUNCTION cdb_geocoder_client._cdb_geocode_ipaddress_point (username text, organization_name text, ip_address text) RETURNS Geometry AS $$ CONNECT cdb_geocoder_client._server_conn_str(); SELECT cdb_geocoder_server.cdb_geocode_ipaddress_point (username, organization_name, ip_address); $$ LANGUAGE plproxy; -- 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_geocoder_client FROM PUBLIC, publicuser CASCADE; -- Grant permissions on the schema to publicuser (but just the schema) GRANT USAGE ON SCHEMA cdb_geocoder_client TO publicuser; -- Revoke execute permissions on all functions in the schema by default REVOKE EXECUTE ON ALL FUNCTIONS IN SCHEMA cdb_geocoder_client FROM PUBLIC, publicuser; GRANT EXECUTE ON FUNCTION cdb_geocoder_client.cdb_geocode_admin0_polygon(country_name text) TO publicuser; GRANT EXECUTE ON FUNCTION cdb_geocoder_client.cdb_geocode_admin1_polygon(admin1_name text) TO publicuser; GRANT EXECUTE ON FUNCTION cdb_geocoder_client.cdb_geocode_admin1_polygon(admin1_name text, country_name text) TO publicuser; GRANT EXECUTE ON FUNCTION cdb_geocoder_client.cdb_geocode_namedplace_point(city_name text) TO publicuser; GRANT EXECUTE ON FUNCTION cdb_geocoder_client.cdb_geocode_namedplace_point(city_name text, country_name text) TO publicuser; GRANT EXECUTE ON FUNCTION cdb_geocoder_client.cdb_geocode_namedplace_point(city_name text, admin1_name text, country_name text) TO publicuser; GRANT EXECUTE ON FUNCTION cdb_geocoder_client.cdb_geocode_postalcode_polygon(postal_code text, country_name text) TO publicuser; GRANT EXECUTE ON FUNCTION cdb_geocoder_client.cdb_geocode_postalcode_point(postal_code text, country_name text) TO publicuser; GRANT EXECUTE ON FUNCTION cdb_geocoder_client.cdb_geocode_ipaddress_point(ip_address text) TO publicuser;