From bd5ae84e903c4f7338683a4db2cb4dc868ce38b4 Mon Sep 17 00:00:00 2001 From: Javier Goizueta Date: Mon, 18 Apr 2016 18:49:58 +0200 Subject: [PATCH 1/4] Optimize CDB_ColumnNames This implementation is about 1000 times faster --- scripts-available/CDB_ColumnNames.sql | 16 +++++++--------- 1 file changed, 7 insertions(+), 9 deletions(-) diff --git a/scripts-available/CDB_ColumnNames.sql b/scripts-available/CDB_ColumnNames.sql index ce74216..22842bd 100644 --- a/scripts-available/CDB_ColumnNames.sql +++ b/scripts-available/CDB_ColumnNames.sql @@ -2,15 +2,13 @@ CREATE OR REPLACE FUNCTION CDB_ColumnNames(REGCLASS) RETURNS SETOF information_schema.sql_identifier AS $$ - - 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 - ORDER BY ordinal_position; - + SELECT + a.attname::information_schema.sql_identifier column_name + FROM pg_class c + LEFT JOIN pg_catalog.pg_attribute a ON a.attrelid = c.oid + WHERE c.oid = $1::oid + AND a.attstattarget = -1 + ORDER BY a.attnum; $$ LANGUAGE SQL; -- This is to migrate from pre-0.2.0 version From 06ebb27160aa1de38d091bc21a75629dc44fd0d7 Mon Sep 17 00:00:00 2001 From: Javier Goizueta Date: Mon, 18 Apr 2016 18:50:37 +0200 Subject: [PATCH 2/4] Optimize internal funcion _cdb_unlimited_text_column --- scripts-available/CDB_Overviews.sql | 17 ++++++++--------- 1 file changed, 8 insertions(+), 9 deletions(-) diff --git a/scripts-available/CDB_Overviews.sql b/scripts-available/CDB_Overviews.sql index 699ca5c..04de527 100644 --- a/scripts-available/CDB_Overviews.sql +++ b/scripts-available/CDB_Overviews.sql @@ -520,15 +520,14 @@ CREATE OR REPLACE FUNCTION _cdb_unlimited_text_column(reloid REGCLASS, col_name RETURNS BOOLEAN AS $$ SELECT EXISTS ( - SELECT * - FROM information_schema.columns c, pg_class _tn, pg_namespace _sn - WHERE table_name = _tn.relname - AND table_schema = _sn.nspname - AND c.column_name = col_name - AND _tn.oid = reloid - AND _sn.oid = _tn.relnamespace - AND character_maximum_length IS NULL - AND c.data_type IN ('text', 'character varying', 'character') + SELECT a.attname + FROM pg_class c + LEFT JOIN pg_catalog.pg_attribute a ON a.attrelid = c.oid + LEFT JOIN pg_catalog.pg_type t ON t.oid = a.atttypid + WHERE c.oid = reloid + AND a.attname = col_name + AND pg_catalog.format_type(a.atttypid, NULL) IN ('text', 'character varying', 'character') + AND pg_catalog.format_type(a.atttypid, NULL) = pg_catalog.format_type(a.atttypid, a.atttypmod) ); $$ LANGUAGE SQL STABLE; From 65415bb335b67266a076f527d7a11dafa5043d9c Mon Sep 17 00:00:00 2001 From: Javier Goizueta Date: Mon, 18 Apr 2016 19:07:33 +0200 Subject: [PATCH 3/4] Optimize funcion CDB_COlumnType --- scripts-available/CDB_ColumnType.sql | 16 +++++++--------- 1 file changed, 7 insertions(+), 9 deletions(-) diff --git a/scripts-available/CDB_ColumnType.sql b/scripts-available/CDB_ColumnType.sql index 8ddc36b..eedc4a0 100644 --- a/scripts-available/CDB_ColumnType.sql +++ b/scripts-available/CDB_ColumnType.sql @@ -2,15 +2,13 @@ CREATE OR REPLACE FUNCTION CDB_ColumnType(REGCLASS, TEXT) RETURNS information_schema.character_data AS $$ - - 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; - + SELECT + pg_catalog.format_type(a.atttypid, NULL)::information_schema.character_data data_type + FROM pg_class c + LEFT JOIN pg_catalog.pg_attribute a ON a.attrelid = c.oid + WHERE c.oid = $1::oid + AND a.attname = $2 + AND a.attstattarget = -1; $$ LANGUAGE SQL; -- This is to migrate from pre-0.2.0 version From 11ad45306f289f9e4b6d71cdc7a6a4f8c52833fa Mon Sep 17 00:00:00 2001 From: Javier Goizueta Date: Mon, 25 Apr 2016 16:30:58 +0200 Subject: [PATCH 4/4] Remove unneeded pg_catalog schema name --- scripts-available/CDB_ColumnNames.sql | 4 ++-- scripts-available/CDB_ColumnType.sql | 6 +++--- scripts-available/CDB_Overviews.sql | 8 ++++---- 3 files changed, 9 insertions(+), 9 deletions(-) diff --git a/scripts-available/CDB_ColumnNames.sql b/scripts-available/CDB_ColumnNames.sql index 22842bd..c35ba99 100644 --- a/scripts-available/CDB_ColumnNames.sql +++ b/scripts-available/CDB_ColumnNames.sql @@ -5,9 +5,9 @@ AS $$ SELECT a.attname::information_schema.sql_identifier column_name FROM pg_class c - LEFT JOIN pg_catalog.pg_attribute a ON a.attrelid = c.oid + LEFT JOIN pg_attribute a ON a.attrelid = c.oid WHERE c.oid = $1::oid - AND a.attstattarget = -1 + AND a.attstattarget < 0 -- exclude system columns ORDER BY a.attnum; $$ LANGUAGE SQL; diff --git a/scripts-available/CDB_ColumnType.sql b/scripts-available/CDB_ColumnType.sql index eedc4a0..19b8934 100644 --- a/scripts-available/CDB_ColumnType.sql +++ b/scripts-available/CDB_ColumnType.sql @@ -3,12 +3,12 @@ CREATE OR REPLACE FUNCTION CDB_ColumnType(REGCLASS, TEXT) RETURNS information_schema.character_data AS $$ SELECT - pg_catalog.format_type(a.atttypid, NULL)::information_schema.character_data data_type + format_type(a.atttypid, NULL)::information_schema.character_data data_type FROM pg_class c - LEFT JOIN pg_catalog.pg_attribute a ON a.attrelid = c.oid + LEFT JOIN pg_attribute a ON a.attrelid = c.oid WHERE c.oid = $1::oid AND a.attname = $2 - AND a.attstattarget = -1; + AND a.attstattarget < 0; -- exclude system columns $$ LANGUAGE SQL; -- This is to migrate from pre-0.2.0 version diff --git a/scripts-available/CDB_Overviews.sql b/scripts-available/CDB_Overviews.sql index 04de527..0e692e7 100644 --- a/scripts-available/CDB_Overviews.sql +++ b/scripts-available/CDB_Overviews.sql @@ -522,12 +522,12 @@ AS $$ SELECT EXISTS ( SELECT a.attname FROM pg_class c - LEFT JOIN pg_catalog.pg_attribute a ON a.attrelid = c.oid - LEFT JOIN pg_catalog.pg_type t ON t.oid = a.atttypid + LEFT JOIN pg_attribute a ON a.attrelid = c.oid + LEFT JOIN pg_type t ON t.oid = a.atttypid WHERE c.oid = reloid AND a.attname = col_name - AND pg_catalog.format_type(a.atttypid, NULL) IN ('text', 'character varying', 'character') - AND pg_catalog.format_type(a.atttypid, NULL) = pg_catalog.format_type(a.atttypid, a.atttypmod) + AND format_type(a.atttypid, NULL) IN ('text', 'character varying', 'character') + AND format_type(a.atttypid, NULL) = format_type(a.atttypid, a.atttypmod) ); $$ LANGUAGE SQL STABLE;