Skip to content

Commit

Permalink
Merge pull request #261 from tsaluszewski/master
Browse files Browse the repository at this point in the history
TableCreationScripts for PostgreSQL do not handle schema name properly.
  • Loading branch information
BiggerNoise authored Oct 11, 2017
2 parents 0a6109d + 1ba8c7f commit 742632c
Show file tree
Hide file tree
Showing 5 changed files with 88 additions and 76 deletions.
13 changes: 8 additions & 5 deletions product/roundhouse.databases.postgresql/PostgreSQLDatabase.cs
Original file line number Diff line number Diff line change
Expand Up @@ -144,14 +144,17 @@ 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 table [{0}_{1}].", roundhouse_schema_name, version_table_name);
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);

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);
}
Expand Down
145 changes: 77 additions & 68 deletions product/roundhouse.databases.postgresql/TableCreationScripts.cs
Original file line number Diff line number Diff line change
Expand Up @@ -2,124 +2,133 @@
{
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);
public static string create_roundhouse_version_table(string roundhouse_schema_name, string version_table_name)
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)
{
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);
}
}
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -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();
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -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();
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -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();
Expand Down

0 comments on commit 742632c

Please sign in to comment.