diff --git a/scripts-available/CDB_ColumnNames.sql b/scripts-available/CDB_ColumnNames.sql index 693ba3d..ebaf0b7 100644 --- a/scripts-available/CDB_ColumnNames.sql +++ b/scripts-available/CDB_ColumnNames.sql @@ -3,11 +3,12 @@ CREATE OR REPLACE FUNCTION CDB_ColumnNames(REGCLASS) RETURNS SETOF information_schema.sql_identifier AS $$ - SELECT column_name - FROM information_schema.columns - WHERE - table_name IN (SELECT CDB_UserTables()) - AND table_name = '' || $1 || ''; + SELECT c.column_name + FROM information_schema.columns c, pg_class _tn, pg_namespace _sn + WHERE table_name = _tn.relname + AND table_schema = _sn.nspname + AND _tn.oid = $1::oid + AND _sn.oid = _tn.relnamespace; $$ LANGUAGE SQL; diff --git a/scripts-available/CDB_ColumnType.sql b/scripts-available/CDB_ColumnType.sql index f887771..8ddc36b 100644 --- a/scripts-available/CDB_ColumnType.sql +++ b/scripts-available/CDB_ColumnType.sql @@ -3,12 +3,13 @@ CREATE OR REPLACE FUNCTION CDB_ColumnType(REGCLASS, TEXT) RETURNS information_schema.character_data AS $$ - SELECT data_type - FROM information_schema.columns - WHERE - table_name IN (SELECT CDB_UserTables()) - AND table_name = '' || $1 || '' - AND column_name = '' || quote_ident($2) || ''; + SELECT c.data_type + FROM information_schema.columns c, pg_class _tn, pg_namespace _sn + WHERE table_name = _tn.relname + AND table_schema = _sn.nspname + AND column_name = $2 + AND _tn.oid = $1::oid + AND _sn.oid = _tn.relnamespace; $$ LANGUAGE SQL; diff --git a/scripts-available/CDB_Stats.sql b/scripts-available/CDB_Stats.sql new file mode 100644 index 0000000..e16748c --- /dev/null +++ b/scripts-available/CDB_Stats.sql @@ -0,0 +1,47 @@ +-- +-- Calculate basic statistics of a given dataset +-- +-- @param in_array A numeric array of numbers +-- +-- Returns: statistical quantity chosen +-- +-- References: http://www.itl.nist.gov/div898/handbook/eda/section3/eda35b.htm +-- + +-- Calculate kurtosis +CREATE OR REPLACE FUNCTION CDB_Kurtosis ( in_array NUMERIC[] ) RETURNS NUMERIC as $$ +DECLARE + a numeric; + c numeric; + s numeric; + k numeric; +BEGIN + SELECT AVG(e), COUNT(e)::numeric, stddev(e) INTO a, c, s FROM ( SELECT unnest(in_array) e ) x; + + EXECUTE 'SELECT sum(power($1 - e, 4)) / ( $2 * power($3, 4)) - 3 + FROM (SELECT unnest($4) e ) x' + INTO k + USING a, c, s, in_array; + + RETURN k; +END; +$$ language plpgsql IMMUTABLE; + +-- Calculate skewness +CREATE OR REPLACE FUNCTION CDB_Skewness ( in_array NUMERIC[] ) RETURNS NUMERIC as $$ +DECLARE + a numeric; + c numeric; + s numeric; + sk numeric; +BEGIN + SELECT AVG(e), COUNT(e)::numeric, stddev(e) INTO a, c, s FROM ( SELECT unnest(in_array) e ) x; + + EXECUTE 'SELECT sum(power($1 - e, 3)) / ( $2 * power($3, 3)) + FROM (SELECT unnest($4) e ) x' + INTO sk + USING a, c, s, in_array; + + RETURN sk; +END; +$$ language plpgsql IMMUTABLE; diff --git a/scripts-enabled/CDB_Stats.sql b/scripts-enabled/CDB_Stats.sql new file mode 120000 index 0000000..37abd7b --- /dev/null +++ b/scripts-enabled/CDB_Stats.sql @@ -0,0 +1 @@ +../scripts-available/CDB_Stats.sql \ No newline at end of file diff --git a/test/CDB_StatsTest.sql b/test/CDB_StatsTest.sql new file mode 100644 index 0000000..571d323 --- /dev/null +++ b/test/CDB_StatsTest.sql @@ -0,0 +1,16 @@ +-- continuous uniform distribution has kurtosis = -6/5, skewness = 0.0 +-- http://mathworld.wolfram.com/UniformDistribution.html +set client_min_messages to ERROR; + +With dist As ( + SELECT random()::numeric As val + FROM generate_series(1,50000) t +) + +SELECT + -- does random dist values match within 1% of known values + abs(CDB_Kurtosis(array_agg(val)) + 1.20) < 1e-2 As kurtosis, + abs(CDB_Skewness(array_agg(val)) - 0) < 1e-2 As skewness +FROM dist; + +set client_min_messages to NOTICE; diff --git a/test/CDB_StatsTest_expect b/test/CDB_StatsTest_expect new file mode 100644 index 0000000..fdc125d --- /dev/null +++ b/test/CDB_StatsTest_expect @@ -0,0 +1,3 @@ +SET +t|t +SET diff --git a/test/extension/run_at_cartodb_schema.sql b/test/extension/run_at_cartodb_schema.sql index c3792ff..0c09e5f 100644 --- a/test/extension/run_at_cartodb_schema.sql +++ b/test/extension/run_at_cartodb_schema.sql @@ -1,4 +1,6 @@ SET SCHEMA 'cartodb'; \i scripts-available/CDB_Quota.sql \i scripts-available/CDB_TableMetadata.sql +\i scripts-available/CDB_ColumnNames.sql +\i scripts-available/CDB_ColumnType.sql SET SCHEMA 'public'; \ No newline at end of file diff --git a/test/extension/test.sh b/test/extension/test.sh index 0eb4977..4c1ecf8 100755 --- a/test/extension/test.sh +++ b/test/extension/test.sh @@ -343,6 +343,40 @@ function test_cdb_tablemetadatatouch_fails_from_user_without_permission() { sql postgres "REVOKE ALL ON CDB_TableMetadata FROM cdb_testmember_1;" } +function test_cdb_column_names() { + sql cdb_testmember_1 'CREATE TABLE cdb_testmember_1.table_cnames(c int, a int, r int, t int, o int);' + sql cdb_testmember_2 'CREATE TABLE cdb_testmember_2.table_cnames(d int, b int);' + + sql cdb_testmember_1 "SELECT string_agg(c,'') from (SELECT cartodb.CDB_ColumnNames('table_cnames') c) as s" should "carto" + sql cdb_testmember_2 "SELECT string_agg(c,'') from (SELECT cartodb.CDB_ColumnNames('table_cnames') c) as s" should "db" + + sql postgres "SELECT string_agg(c,'') from (SELECT cartodb.CDB_ColumnNames('cdb_testmember_1.table_cnames'::regclass) c) as s" should "carto" + sql postgres "SELECT string_agg(c,'') from (SELECT cartodb.CDB_ColumnNames('cdb_testmember_2.table_cnames') c) as s" should "db" + + # Using schema from owner + sql cdb_testmember_1 "SELECT string_agg(c,'') from (SELECT cartodb.CDB_ColumnNames('cdb_testmember_1.table_cnames') c) as s" should "carto" + + ## it's not possible to get column names from a table where you don't have permissions + sql cdb_testmember_2 "SELECT string_agg(c,'') from (SELECT cartodb.CDB_ColumnNames('cdb_testmember_1.table_cnames') c) as s" fails + + sql cdb_testmember_1 'DROP TABLE cdb_testmember_1.table_cnames' + sql cdb_testmember_2 'DROP TABLE cdb_testmember_2.table_cnames' +} + +function test_cdb_column_type() { + sql cdb_testmember_1 'CREATE TABLE cdb_testmember_1.table_ctype(c int, a int, r int, t int, o int);' + sql cdb_testmember_2 'CREATE TABLE cdb_testmember_2.table_ctype(c text, a text, r text, t text, o text);' + + sql cdb_testmember_1 "SELECT cartodb.CDB_ColumnType('table_ctype', 'c')" should "integer" + sql cdb_testmember_2 "SELECT cartodb.CDB_ColumnType('table_ctype', 'c')" should "text" + + sql postgres "SELECT cartodb.CDB_ColumnType('cdb_testmember_1.table_ctype', 'c')" should "integer" + sql postgres "SELECT cartodb.CDB_ColumnType('cdb_testmember_2.table_ctype', 'c')" should "text" + + sql cdb_testmember_1 'DROP TABLE cdb_testmember_1.table_ctype' + sql cdb_testmember_2 'DROP TABLE cdb_testmember_2.table_ctype' +} + function test_cdb_querytables_schema_and_table_names_with_dots() { ${CMD} -d ${DATABASE} -f scripts-available/CDB_QueryStatements.sql ${CMD} -d ${DATABASE} -f scripts-available/CDB_QueryTables.sql