From 11c0f113e36ad5f38bf7de2aac364c9f2c9dc7e3 Mon Sep 17 00:00:00 2001 From: tsaluszewski Date: Tue, 2 Aug 2016 14:53:49 +0200 Subject: [PATCH 1/2] TableCreationScripts for PostgreSQL do not handle schema name properly #260. --- .../PostgreSQLDatabase.cs | 6 +- .../TableCreationScripts.cs | 110 ++++++++++-------- .../orm/ScriptsRunErrorMapping.cs | 2 +- .../orm/ScriptsRunMapping.cs | 2 +- .../orm/VersionMapping.cs | 2 +- 5 files changed, 65 insertions(+), 57 deletions(-) diff --git a/product/roundhouse.databases.postgresql/PostgreSQLDatabase.cs b/product/roundhouse.databases.postgresql/PostgreSQLDatabase.cs index 48fd66cc..6db65c9b 100644 --- a/product/roundhouse.databases.postgresql/PostgreSQLDatabase.cs +++ b/product/roundhouse.databases.postgresql/PostgreSQLDatabase.cs @@ -138,12 +138,12 @@ public override void create_or_update_roundhouse_tables() { //Log.bound_to(this).log_an_info_event_containing("Creating schema [{0}].", roundhouse_schema_name); //run_sql(TableCreationScripts.create_roundhouse_schema(roundhouse_schema_name), ConnectionType.Default); - Log.bound_to(this).log_an_info_event_containing("Creating table [{0}_{1}].", roundhouse_schema_name, version_table_name); + Log.bound_to(this).log_an_info_event_containing("Creating table [{0}].[{1}].", roundhouse_schema_name, version_table_name); run_sql(TableCreationScripts.create_roundhouse_version_table(roundhouse_schema_name, version_table_name), ConnectionType.Default); - Log.bound_to(this).log_an_info_event_containing("Creating table [{0}_{1}].", roundhouse_schema_name, scripts_run_table_name); + Log.bound_to(this).log_an_info_event_containing("Creating table [{0}].[{1}].", roundhouse_schema_name, scripts_run_table_name); run_sql(TableCreationScripts.create_roundhouse_scripts_run_table(roundhouse_schema_name, version_table_name, scripts_run_table_name), ConnectionType.Default); - Log.bound_to(this).log_an_info_event_containing("Creating table [{0}_{1}].", roundhouse_schema_name, scripts_run_errors_table_name); + Log.bound_to(this).log_an_info_event_containing("Creating table [{0}].[{1}].", roundhouse_schema_name, scripts_run_errors_table_name); run_sql(TableCreationScripts.create_roundhouse_scripts_run_errors_table(roundhouse_schema_name, scripts_run_errors_table_name), ConnectionType.Default); } diff --git a/product/roundhouse.databases.postgresql/TableCreationScripts.cs b/product/roundhouse.databases.postgresql/TableCreationScripts.cs index fae96562..7745a0fc 100644 --- a/product/roundhouse.databases.postgresql/TableCreationScripts.cs +++ b/product/roundhouse.databases.postgresql/TableCreationScripts.cs @@ -22,104 +22,112 @@ public sealed class TableCreationScripts public static string create_roundhouse_version_table(string roundhouse_schema_name, string version_table_name) { return string.Format(@" -CREATE FUNCTION CreateRoundHouseVersionTable(in tblName varchar) RETURNS void AS $$ +CREATE OR REPLACE FUNCTION CreateRoundHouseVersionTable(in schName varchar, in tblName varchar) RETURNS void AS $$ DECLARE t_exists integer; t_user varchar(255); + t_table varchar(255); BEGIN - SELECT INTO t_exists COUNT(*) FROM pg_tables WHERE tablename = lower($1); - SELECT current_user into t_user; + SELECT INTO t_exists COUNT(*) FROM pg_tables WHERE schemaname = lower(schName) and tablename = lower(tblName); + SELECT current_user into t_user; + SELECT lower(schName) || '.' || lower(tblName) into t_table; + IF t_exists = 0 THEN - EXECUTE 'CREATE TABLE ' || lower(tblName) || ' + EXECUTE 'CREATE TABLE ' || t_table || ' ( - id serial NOT NULL + id serial NOT NULL ,repository_path varchar(255) NULL - ,version varchar(50) NULL - ,entry_date timestamp NOT NULL default current_timestamp - ,modified_date timestamp NOT NULL default current_timestamp - ,entered_by varchar(50) NULL + ,version varchar(50) NULL + ,entry_date timestamp NOT NULL default current_timestamp + ,modified_date timestamp NOT NULL default current_timestamp + ,entered_by varchar(50) NULL ); - alter table ' || lower(tblName) || ' add constraint ' || lower(tblName || '_pk') || ' primary key (id); - -- alter table ' || lower(tblName) || ' OWNER TO postgres; - GRANT SELECT ON TABLE ' || lower(tblName) || ' TO public; - --GRANT ALL ON TABLE ' || lower(tblName) || ' TO t_user;'; + + alter table ' || t_table || ' add constraint ' || replace(t_table, '.', '_') || '_pk' || ' primary key (id); + GRANT SELECT ON TABLE ' || t_table || ' TO public;'; END IF; END; $$ LANGUAGE 'plpgsql'; -SELECT CreateRoundHouseVersionTable('{0}_{1}'); -DROP FUNCTION CreateRoundHouseVersionTable(in tblName varchar); +SELECT CreateRoundHouseVersionTable('{0}','{1}'); +DROP FUNCTION CreateRoundHouseVersionTable(in schName varchar, in tblName varchar); ", roundhouse_schema_name, version_table_name); } public static string create_roundhouse_scripts_run_table(string roundhouse_schema_name, string version_table_name, string scripts_run_table_name) { return string.Format(@" -CREATE FUNCTION CreateRoundHouseScriptsRunTable(in versionTblName varchar, in tblName varchar) RETURNS void AS $$ +CREATE OR REPLACE FUNCTION CreateRoundHouseScriptsRunTable(in schName varchar, in versionTblName varchar, in tblName varchar) RETURNS void AS $$ DECLARE t_exists integer; t_user varchar(255); + t_table varchar(255); + t_version_table varchar(255); BEGIN - SELECT INTO t_exists COUNT(*) FROM pg_tables WHERE tablename = lower($2); - SELECT current_user into t_user; + SELECT INTO t_exists COUNT(*) FROM pg_tables WHERE schemaname = lower(schName) and tablename = lower(tblName); + SELECT current_user into t_user; + SELECT lower(schName) || '.' || lower(tblName) into t_table; + SELECT lower(schName) || '.' || lower(versionTblName) into t_version_table; + IF t_exists = 0 THEN - EXECUTE 'CREATE TABLE ' || lower(tblName) || ' + EXECUTE 'CREATE TABLE ' || t_table || ' ( - id serial NOT NULL - ,version_id integer NULL - ,script_name varchar(255) NULL + id serial NOT NULL + ,version_id integer NULL + ,script_name varchar(255) NULL ,text_of_script text NULL - ,text_hash varchar(512) NULL + ,text_hash varchar(512) NULL ,one_time_script boolean NULL default false - ,entry_date timestamp NOT NULL default current_timestamp + ,entry_date timestamp NOT NULL default current_timestamp ,modified_date timestamp NOT NULL default current_timestamp - ,entered_by varchar(50) NULL + ,entered_by varchar(50) NULL ); - alter table ' || lower(tblName) || ' add constraint ' || lower(tblName || '_pk') || ' primary key (id); - alter table ' || lower(tblName) || ' add constraint ' || lower(tblName || '_' || versionTblName || '_fk') || ' foreign key (version_id) references ' || lower(versionTblName) || ' (id); - -- alter table ' || lower(tblName) || ' OWNER TO postgres; - GRANT SELECT ON TABLE ' || lower(tblName) || ' TO public; - --GRANT ALL ON TABLE ' || lower(tblName) || ' TO t_user;'; + + alter table ' || t_table || ' add constraint ' || replace(t_table, '.', '_') || '_pk' || ' primary key (id); + alter table ' || t_table || ' add constraint ' || replace(t_table, '.', '_') || '_' || versionTblName || '_fk' || ' foreign key (version_id) references ' || t_version_table || ' (id); + GRANT SELECT ON TABLE ' || t_table || ' TO public;'; END IF; END; $$ LANGUAGE 'plpgsql'; -SELECT CreateRoundHouseScriptsRunTable('{0}_{2}', '{0}_{1}'); -DROP FUNCTION CreateRoundHouseScriptsRunTable(in versionTblName varchar, in tblName varchar); -", roundhouse_schema_name, scripts_run_table_name, version_table_name); +SELECT CreateRoundHouseScriptsRunTable('{0}', '{1}', '{2}'); +DROP FUNCTION CreateRoundHouseScriptsRunTable(in schName varchar, in versionTblName varchar, in tblName varchar); +", roundhouse_schema_name, version_table_name, scripts_run_table_name); } public static string create_roundhouse_scripts_run_errors_table(string roundhouse_schema_name, string scripts_run_errors_table_name) { return string.Format(@" -CREATE FUNCTION CreateRoundHouseScriptsRunErrorsTable(in tblName varchar) RETURNS void AS $$ +CREATE OR REPLACE FUNCTION CreateRoundHouseScriptsRunErrorsTable(in schName varchar, in tblName varchar) RETURNS void AS $$ DECLARE t_exists integer; t_user varchar(255); + t_table varchar(255); BEGIN - SELECT INTO t_exists COUNT(*) FROM pg_tables WHERE tablename = lower($1); - SELECT current_user into t_user; + SELECT INTO t_exists COUNT(*) FROM pg_tables WHERE schemaname = lower(schName) and tablename = lower(tblName); + SELECT current_user into t_user; + SELECT lower(schName) || '.' || lower(tblName) into t_table; + IF t_exists = 0 THEN - EXECUTE 'CREATE TABLE ' || lower(tblName) || ' + EXECUTE 'CREATE TABLE ' || t_table || ' ( - id serial NOT NULL + id serial NOT NULL ,repository_path varchar(255) NULL - ,version varchar(50) NULL + ,version varchar(50) NULL ,script_name varchar(255) NULL - ,text_of_script text NULL - ,erroneous_part_of_script text NULL - ,error_message text NULL - ,entry_date timestamp NOT NULL default current_timestamp - ,modified_date timestamp NOT NULL default current_timestamp - ,entered_by varchar(50) NULL + ,text_of_script text NULL + ,erroneous_part_of_script text NULL + ,error_message text NULL + ,entry_date timestamp NOT NULL default current_timestamp + ,modified_date timestamp NOT NULL default current_timestamp + ,entered_by varchar(50) NULL ); - alter table ' || lower(tblName) || ' add constraint ' || lower(tblName || '_pk') || ' primary key (id); - -- alter table ' || lower(tblName) || ' OWNER TO postgres; - GRANT SELECT ON TABLE ' || lower(tblName) || ' TO public; - --GRANT ALL ON TABLE ' || lower(tblName) || ' TO t_user;'; + + alter table ' || t_table || ' add constraint ' || replace(t_table, '.', '_') || '_pk' || ' primary key (id); + GRANT SELECT ON TABLE ' || t_table || ' TO public;'; END IF; END; $$ LANGUAGE 'plpgsql'; -SELECT CreateRoundHouseScriptsRunErrorsTable('{0}_{1}'); -DROP FUNCTION CreateRoundHouseScriptsRunErrorsTable(in tblName varchar); +SELECT CreateRoundHouseScriptsRunErrorsTable('{0}','{1}'); +DROP FUNCTION CreateRoundHouseScriptsRunErrorsTable(in schName varchar, in tblName varchar); ", roundhouse_schema_name, scripts_run_errors_table_name); } } diff --git a/product/roundhouse.databases.postgresql/orm/ScriptsRunErrorMapping.cs b/product/roundhouse.databases.postgresql/orm/ScriptsRunErrorMapping.cs index 022e6611..7a56664c 100644 --- a/product/roundhouse.databases.postgresql/orm/ScriptsRunErrorMapping.cs +++ b/product/roundhouse.databases.postgresql/orm/ScriptsRunErrorMapping.cs @@ -10,7 +10,7 @@ public ScriptsRunErrorMapping() { //HibernateMapping.Schema(ApplicationParameters.CurrentMappings.roundhouse_schema_name); //Table(ApplicationParameters.CurrentMappings.scripts_run_errors_table_name); - Table(ApplicationParameters.CurrentMappings.roundhouse_schema_name + "_" + ApplicationParameters.CurrentMappings.scripts_run_errors_table_name); + Table(ApplicationParameters.CurrentMappings.roundhouse_schema_name + "." + ApplicationParameters.CurrentMappings.scripts_run_errors_table_name); Not.LazyLoad(); HibernateMapping.DefaultAccess.Property(); HibernateMapping.DefaultCascade.SaveUpdate(); diff --git a/product/roundhouse.databases.postgresql/orm/ScriptsRunMapping.cs b/product/roundhouse.databases.postgresql/orm/ScriptsRunMapping.cs index 2824ee98..aabfbb51 100644 --- a/product/roundhouse.databases.postgresql/orm/ScriptsRunMapping.cs +++ b/product/roundhouse.databases.postgresql/orm/ScriptsRunMapping.cs @@ -10,7 +10,7 @@ public ScriptsRunMapping() { //HibernateMapping.Schema(ApplicationParameters.CurrentMappings.roundhouse_schema_name); //Table(ApplicationParameters.CurrentMappings.scripts_run_table_name); - Table(ApplicationParameters.CurrentMappings.roundhouse_schema_name + "_" + ApplicationParameters.CurrentMappings.scripts_run_table_name); + Table(ApplicationParameters.CurrentMappings.roundhouse_schema_name + "." + ApplicationParameters.CurrentMappings.scripts_run_table_name); Not.LazyLoad(); HibernateMapping.DefaultAccess.Property(); HibernateMapping.DefaultCascade.SaveUpdate(); diff --git a/product/roundhouse.databases.postgresql/orm/VersionMapping.cs b/product/roundhouse.databases.postgresql/orm/VersionMapping.cs index 0f111864..dc62b3d4 100644 --- a/product/roundhouse.databases.postgresql/orm/VersionMapping.cs +++ b/product/roundhouse.databases.postgresql/orm/VersionMapping.cs @@ -10,7 +10,7 @@ public VersionMapping() { //HibernateMapping.Schema(ApplicationParameters.CurrentMappings.roundhouse_schema_name); //Table(ApplicationParameters.CurrentMappings.version_table_name); - Table(ApplicationParameters.CurrentMappings.roundhouse_schema_name + "_" + ApplicationParameters.CurrentMappings.version_table_name); + Table(ApplicationParameters.CurrentMappings.roundhouse_schema_name + "." + ApplicationParameters.CurrentMappings.version_table_name); Not.LazyLoad(); HibernateMapping.DefaultAccess.Property(); HibernateMapping.DefaultCascade.SaveUpdate(); From 1ba8c7f148baeac3ab96c05464637838042ea9fd Mon Sep 17 00:00:00 2001 From: tsaluszewski Date: Tue, 2 Aug 2016 19:20:31 +0200 Subject: [PATCH 2/2] TableCreationScripts for PostgreSQL do not handle schema name properly #260. Schema creation script added. --- .../PostgreSQLDatabase.cs | 7 ++-- .../TableCreationScripts.cs | 35 ++++++++++--------- 2 files changed, 23 insertions(+), 19 deletions(-) diff --git a/product/roundhouse.databases.postgresql/PostgreSQLDatabase.cs b/product/roundhouse.databases.postgresql/PostgreSQLDatabase.cs index 6db65c9b..bd097831 100644 --- a/product/roundhouse.databases.postgresql/PostgreSQLDatabase.cs +++ b/product/roundhouse.databases.postgresql/PostgreSQLDatabase.cs @@ -136,13 +136,16 @@ public override string delete_database_script() public override void create_or_update_roundhouse_tables() { - //Log.bound_to(this).log_an_info_event_containing("Creating schema [{0}].", roundhouse_schema_name); - //run_sql(TableCreationScripts.create_roundhouse_schema(roundhouse_schema_name), ConnectionType.Default); + Log.bound_to(this).log_an_info_event_containing("Creating schema [{0}].", roundhouse_schema_name); + run_sql(TableCreationScripts.create_roundhouse_schema(roundhouse_schema_name), ConnectionType.Default); + Log.bound_to(this).log_an_info_event_containing("Creating table [{0}].[{1}].", roundhouse_schema_name, version_table_name); run_sql(TableCreationScripts.create_roundhouse_version_table(roundhouse_schema_name, version_table_name), ConnectionType.Default); + Log.bound_to(this).log_an_info_event_containing("Creating table [{0}].[{1}].", roundhouse_schema_name, scripts_run_table_name); run_sql(TableCreationScripts.create_roundhouse_scripts_run_table(roundhouse_schema_name, version_table_name, scripts_run_table_name), ConnectionType.Default); + Log.bound_to(this).log_an_info_event_containing("Creating table [{0}].[{1}].", roundhouse_schema_name, scripts_run_errors_table_name); run_sql(TableCreationScripts.create_roundhouse_scripts_run_errors_table(roundhouse_schema_name, scripts_run_errors_table_name), ConnectionType.Default); diff --git a/product/roundhouse.databases.postgresql/TableCreationScripts.cs b/product/roundhouse.databases.postgresql/TableCreationScripts.cs index 7745a0fc..8b49fa01 100644 --- a/product/roundhouse.databases.postgresql/TableCreationScripts.cs +++ b/product/roundhouse.databases.postgresql/TableCreationScripts.cs @@ -2,24 +2,25 @@ { public sealed class TableCreationScripts { -// public static string create_roundhouse_schema(string roundhouse_schema_name) -// { -// return string.Format(@" -//CREATE FUNCTION CreateRoundHouseSchema(in schemaName varchar) RETURNS void AS $$ -//DECLARE t_exists integer; -//BEGIN -// SELECT INTO t_exists COUNT(*) FROM information_schema.schemata WHERE schema_name = lower($1); -// IF t_exists = 0 THEN -// EXECUTE 'CREATE SCHEMA ' || lower(schemaName); -// END IF; -//END; -//$$ LANGUAGE 'plpgsql'; -//SELECT CreateRoundHouseSchema('{0}'); -//DROP FUNCTION CreateRoundHouseSchema(in schemaName varchar); -//", roundhouse_schema_name); -// } + public static string create_roundhouse_schema(string roundhouse_schema_name) + { + return string.Format(@" +CREATE OR REPLACE FUNCTION CreateRoundHouseSchema(in schemaName varchar) RETURNS void AS $$ +DECLARE t_exists integer; +BEGIN + SELECT INTO t_exists COUNT(*) FROM information_schema.schemata WHERE schema_name = lower(schemaName); + + IF t_exists = 0 THEN + EXECUTE 'CREATE SCHEMA ' || lower(schemaName); + END IF; +END; +$$ LANGUAGE 'plpgsql'; +SELECT CreateRoundHouseSchema('{0}'); +DROP FUNCTION CreateRoundHouseSchema(in schemaName varchar); +", roundhouse_schema_name); + } - public static string create_roundhouse_version_table(string roundhouse_schema_name, string version_table_name) + public static string create_roundhouse_version_table(string roundhouse_schema_name, string version_table_name) { return string.Format(@" CREATE OR REPLACE FUNCTION CreateRoundHouseVersionTable(in schName varchar, in tblName varchar) RETURNS void AS $$