Merge branch 'master' into 103-Extension_Group_API

This commit is contained in:
Juan Ignacio Sánchez Lara 2015-09-07 13:37:21 +02:00
commit f70fd1a4c7
12 changed files with 188 additions and 18 deletions

View File

@ -1,7 +1,7 @@
# cartodb/Makefile # cartodb/Makefile
EXTENSION = cartodb EXTENSION = cartodb
EXTVERSION = 0.9.4 EXTVERSION = 0.10.0
SED = sed SED = sed
@ -47,6 +47,7 @@ UPGRADABLE = \
0.9.2 \ 0.9.2 \
0.9.3 \ 0.9.3 \
0.9.4 \ 0.9.4 \
0.10.0 \
$(EXTVERSION)dev \ $(EXTVERSION)dev \
$(EXTVERSION)next \ $(EXTVERSION)next \
$(END) $(END)

11
NEWS.md
View File

@ -1,7 +1,14 @@
X.Y.Z (2015-mm-dd) next (2015-mm-dd)
------------------ -----------------
* Groups API * Groups API
0.10.0 (2015-09-07)
-----------------
* Quote schema and table names returned by CDB_QueryTables [#134](https://github.com/CartoDB/cartodb-postgresql/pull/134). Use quote_ident to quote schema and table names when necessary.
* Fixed CDB_ColumnNames [#122](https://github.com/CartoDB/cartodb-postgresql/issues/122) and CDB_ColumnType [#130](https://github.com/CartoDB/cartodb-postgresql/issues/130) should honor regclass, returning columns for just the table in the schema and not in any other one [#131](https://github.com/CartoDB/cartodb-postgresql/pull/131).
* Add kurtosis and skewness [#124](https://github.com/CartoDB/cartodb-postgresql/pull/124).
* Removed `DROP FUNCTION IF EXISTS cdb_usertables(text);` [#129](https://github.com/CartoDB/cartodb-postgresql/pull/129). This was needed for upgrading between 0.7.4 to 0.8.0 but is no longer needed.
0.9.4 (2015-08-28) 0.9.4 (2015-08-28)
------------------ ------------------
* Fixed issue with indices when renaming tables [#123](https://github.com/CartoDB/cartodb-postgresql/issues/123) * Fixed issue with indices when renaming tables [#123](https://github.com/CartoDB/cartodb-postgresql/issues/123)

View File

@ -3,11 +3,12 @@ CREATE OR REPLACE FUNCTION CDB_ColumnNames(REGCLASS)
RETURNS SETOF information_schema.sql_identifier RETURNS SETOF information_schema.sql_identifier
AS $$ AS $$
SELECT column_name SELECT c.column_name
FROM information_schema.columns FROM information_schema.columns c, pg_class _tn, pg_namespace _sn
WHERE WHERE table_name = _tn.relname
table_name IN (SELECT CDB_UserTables()) AND table_schema = _sn.nspname
AND table_name = '' || $1 || ''; AND _tn.oid = $1::oid
AND _sn.oid = _tn.relnamespace;
$$ LANGUAGE SQL; $$ LANGUAGE SQL;

View File

@ -3,12 +3,13 @@ CREATE OR REPLACE FUNCTION CDB_ColumnType(REGCLASS, TEXT)
RETURNS information_schema.character_data RETURNS information_schema.character_data
AS $$ AS $$
SELECT data_type SELECT c.data_type
FROM information_schema.columns FROM information_schema.columns c, pg_class _tn, pg_namespace _sn
WHERE WHERE table_name = _tn.relname
table_name IN (SELECT CDB_UserTables()) AND table_schema = _sn.nspname
AND table_name = '' || $1 || '' AND column_name = $2
AND column_name = '' || quote_ident($2) || ''; AND _tn.oid = $1::oid
AND _sn.oid = _tn.relnamespace;
$$ LANGUAGE SQL; $$ LANGUAGE SQL;

View File

@ -41,11 +41,11 @@ BEGIN
xpath('//x:Relation-Name/text()', exp, ARRAY[ARRAY['x', 'http://www.postgresql.org/2009/explain']]) as x, xpath('//x:Relation-Name/text()', exp, ARRAY[ARRAY['x', 'http://www.postgresql.org/2009/explain']]) as x,
xpath('//x:Relation-Name/../x:Schema/text()', exp, ARRAY[ARRAY['x', 'http://www.postgresql.org/2009/explain']]) as s xpath('//x:Relation-Name/../x:Schema/text()', exp, ARRAY[ARRAY['x', 'http://www.postgresql.org/2009/explain']]) as s
) )
SELECT unnest(x) as p, unnest(s) as sc from inp SELECT unnest(x)::text as p, unnest(s)::text as sc from inp
LOOP LOOP
-- RAISE DEBUG 'tab: %', rec2.p; -- RAISE DEBUG 'tab: %', rec2.p;
-- RAISE DEBUG 'sc: %', rec2.sc; -- RAISE DEBUG 'sc: %', rec2.sc;
tables := array_append(tables, (rec2.sc || '.' || rec2.p)); tables := array_append(tables, format('%s.%s', quote_ident(rec2.sc), quote_ident(rec2.p)));
END LOOP; END LOOP;
-- RAISE DEBUG 'Tables: %', tables; -- RAISE DEBUG 'Tables: %', tables;

View File

@ -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;

View File

@ -5,7 +5,6 @@
-- --
-- Currently accepted permissions are: 'public', 'private' or 'all' -- Currently accepted permissions are: 'public', 'private' or 'all'
-- --
DROP FUNCTION IF EXISTS cdb_usertables(text);
CREATE OR REPLACE FUNCTION CDB_UserTables(perm text DEFAULT 'all') CREATE OR REPLACE FUNCTION CDB_UserTables(perm text DEFAULT 'all')
RETURNS SETOF name RETURNS SETOF name
AS $$ AS $$

View File

@ -0,0 +1 @@
../scripts-available/CDB_Stats.sql

16
test/CDB_StatsTest.sql Normal file
View File

@ -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;

View File

@ -0,0 +1,3 @@
SET
t|t
SET

View File

@ -1,4 +1,6 @@
SET SCHEMA 'cartodb'; SET SCHEMA 'cartodb';
\i scripts-available/CDB_Quota.sql \i scripts-available/CDB_Quota.sql
\i scripts-available/CDB_TableMetadata.sql \i scripts-available/CDB_TableMetadata.sql
\i scripts-available/CDB_ColumnNames.sql
\i scripts-available/CDB_ColumnType.sql
SET SCHEMA 'public'; SET SCHEMA 'public';

View File

@ -178,6 +178,7 @@ function setup() {
sql "CREATE SCHEMA cartodb;" sql "CREATE SCHEMA cartodb;"
sql "GRANT USAGE ON SCHEMA cartodb TO public;" sql "GRANT USAGE ON SCHEMA cartodb TO public;"
sql "CREATE EXTENSION postgis;" sql "CREATE EXTENSION postgis;"
sql "CREATE EXTENSION plpythonu;"
log_info "########################### BOOTSTRAP ###########################" log_info "########################### BOOTSTRAP ###########################"
${CMD} -d ${DATABASE} -f scripts-available/CDB_Organizations.sql ${CMD} -d ${DATABASE} -f scripts-available/CDB_Organizations.sql
@ -227,7 +228,12 @@ function run_tests() {
local TESTS local TESTS
if [[ $# -ge 1 ]] if [[ $# -ge 1 ]]
then then
TESTS="$@" if [[ $# -eq 1 ]]
then
TESTS=`cat $0 | grep -o "$1[^\(]*"`
else
TESTS="$@"
fi
else else
TESTS=`cat $0 | perl -n -e'/function (test.*)\(\)/ && print "$1\n"'` TESTS=`cat $0 | perl -n -e'/function (test.*)\(\)/ && print "$1\n"'`
fi fi
@ -337,6 +343,92 @@ function test_cdb_tablemetadatatouch_fails_from_user_without_permission() {
sql postgres "REVOKE ALL ON CDB_TableMetadata FROM cdb_testmember_1;" 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
sql postgres 'CREATE SCHEMA "foo.bar";'
sql postgres 'CREATE TABLE "foo.bar"."c.a.r.t.o.d.b" (a int);'
sql postgres 'INSERT INTO "foo.bar"."c.a.r.t.o.d.b" values (1);'
sql postgres 'SELECT a FROM "foo.bar"."c.a.r.t.o.d.b";' should 1
sql postgres 'SELECT CDB_QueryTablesText($q$select * from "foo.bar"."c.a.r.t.o.d.b"$q$);' should '{"\"foo.bar\".\"c.a.r.t.o.d.b\""}'
sql postgres 'SELECT CDB_QueryTables($q$select * from "foo.bar"."c.a.r.t.o.d.b"$q$);' should '{"\"foo.bar\".\"c.a.r.t.o.d.b\""}'
sql postgres 'DROP TABLE "foo.bar"."c.a.r.t.o.d.b";'
sql postgres 'DROP SCHEMA "foo.bar";'
}
function test_cdb_querytables_table_name_with_dots() {
${CMD} -d ${DATABASE} -f scripts-available/CDB_QueryStatements.sql
${CMD} -d ${DATABASE} -f scripts-available/CDB_QueryTables.sql
sql postgres 'CREATE TABLE "w.a.d.u.s" (a int);';
sql postgres 'SELECT CDB_QueryTablesText($q$select * from "w.a.d.u.s"$q$);' should '{"public.\"w.a.d.u.s\""}'
sql postgres 'SELECT CDB_QueryTables($q$select * from "w.a.d.u.s"$q$);' should '{"public.\"w.a.d.u.s\""}'
sql postgres 'DROP TABLE "w.a.d.u.s";';
}
function test_cdb_querytables_happy_cases() {
${CMD} -d ${DATABASE} -f scripts-available/CDB_QueryStatements.sql
${CMD} -d ${DATABASE} -f scripts-available/CDB_QueryTables.sql
sql postgres 'CREATE TABLE wadus (a int);';
sql postgres 'CREATE TABLE "FOOBAR" (a int);';
sql postgres 'CREATE SCHEMA foo;'
sql postgres 'CREATE TABLE foo.wadus (a int);';
## See how it does NOT quote anything here
sql postgres 'SELECT CDB_QueryTablesText($q$select * from wadus$q$);' should '{public.wadus}'
sql postgres 'SELECT CDB_QueryTablesText($q$select * from foo.wadus$q$);' should '{foo.wadus}'
sql postgres 'SELECT CDB_QueryTables($q$select * from wadus$q$);' should '{public.wadus}'
sql postgres 'SELECT CDB_QueryTables($q$select * from foo.wadus$q$);' should '{foo.wadus}'
## But it quotes when it's needed even if table name has no dots but was created with quotes
sql postgres 'SELECT CDB_QueryTablesText($q$select * from "FOOBAR"$q$);' should '{"public.\"FOOBAR\""}'
sql postgres 'DROP TABLE wadus;'
sql postgres 'DROP TABLE "FOOBAR";'
sql postgres 'DROP TABLE foo.wadus;'
sql postgres 'DROP SCHEMA foo;'
}
#################################################### TESTS END HERE #################################################### #################################################### TESTS END HERE ####################################################
run_tests $@ run_tests $@