Re: [GENERAL] clone_schema function

2017-02-14 Thread Melvin Davidson
On Tue, Feb 14, 2017 at 7:46 AM, Michael Librodo
  wrote:

> I had to modify the portion that copies FK constraint:
>
> https://gist.github.com/mlibrodo/6f246c483e650dc716eba752a9d3c79a
>
> Basically, the issue on my end was that the FK constraints on the
> cloned(destination) schema seem to reference the source_schema
>
>
>
> --
> Sent via pgsql-general mailing list (pgsql-general@postgresql.org)
> To make changes to your subscription:
> http://www.postgresql.org/mailpref/pgsql-general
>

Michael,
Perhaps you can combine that code with the original by Emanuel '3manuek'
and that I modified to be more inclusive
of additional objects. See attached.

-- 
*Melvin Davidson*
I reserve the right to fantasize.  Whether or not you
wish to share my fantasy is entirely up to you.
-- Function: clone_schema(text, text, boolean)

-- DROP FUNCTION clone_schema(text, text, boolean);

CREATE OR REPLACE FUNCTION clone_schema(
source_schema text,
dest_schema text,
include_recs boolean)
  RETURNS void AS
$BODY$
--  Initial code by Emanuel '3manuek' 
--  Last revision 2015-09-20 by Melvin Davidson
--  This function will clone all sequences, tables, indexes, rules, triggers, 
--  data(optional), views & functions from any existing schema to a new schema
-- SAMPLE CALL:
-- SELECT clone_schema('public', 'new_schema', TRUE);

DECLARE
  src_oid  oid;
  tbl_oid  oid;
  func_oid oid;
  con_oid  oid;
  v_path   text;
  v_func   text;
  v_args   text;
  v_connametext;
  v_rule   text;
  v_trig   text;
  object   text;
  buffer   text;
  srctbl   text;
  default_ text;
  v_column text;
  qry  text;
  dest_qry text;
  v_deftext;
  v_stat   integer;
  seqval   bigint;
  sq_last_valuebigint;
  sq_max_value bigint;
  sq_start_value   bigint;
  sq_increment_by  bigint;
  sq_min_value bigint;
  sq_cache_value   bigint;
  sq_log_cnt   bigint;
  sq_is_called boolean;
  sq_is_cycled boolean;
  sq_cycledchar(10);

BEGIN

-- Check that source_schema exists
  SELECT oid INTO src_oid
FROM pg_namespace
   WHERE nspname = quote_ident(source_schema);
  IF NOT FOUND
THEN 
RAISE NOTICE 'source schema % does not exist!', source_schema;
RETURN ;
  END IF;

  -- Check that dest_schema does not yet exist
  PERFORM nspname 
FROM pg_namespace
   WHERE nspname = quote_ident(dest_schema);
  IF FOUND
THEN 
RAISE NOTICE 'dest schema % already exists!', dest_schema;
RETURN ;
  END IF;

  EXECUTE 'CREATE SCHEMA ' || quote_ident(dest_schema) ;

  -- Add schema comment
  SELECT description INTO v_def
FROM pg_description
   WHERE objoid = src_oid
   AND objsubid = 0;
  IF FOUND 
THEN 
  EXECUTE 'COMMENT ON SCHEMA ' || quote_ident(dest_schema) || ' IS ' || 
quote_literal(v_def);
  END IF;
  
  -- Create sequences
  -- TODO: Find a way to make this sequence's owner is the correct table.
  FOR object IN
SELECT sequence_name::text 
  FROM information_schema.sequences
 WHERE sequence_schema = quote_ident(source_schema)
  LOOP
EXECUTE 'CREATE SEQUENCE ' || quote_ident(dest_schema) || '.' || 
quote_ident(object);
srctbl := quote_ident(source_schema) || '.' || quote_ident(object);

EXECUTE 'SELECT last_value, max_value, start_value, increment_by, 
min_value, cache_value, log_cnt, is_cycled, is_called 
  FROM ' || quote_ident(source_schema) || '.' || 
quote_ident(object) || ';' 
  INTO sq_last_value, sq_max_value, sq_start_value, 
sq_increment_by, sq_min_value, sq_cache_value, sq_log_cnt, sq_is_cycled, 
sq_is_called ; 

IF sq_is_cycled 
  THEN 
sq_cycled := 'CYCLE';
ELSE
sq_cycled := 'NO CYCLE';
END IF;

EXECUTE 'ALTER SEQUENCE '   || quote_ident(dest_schema) || '.' || 
quote_ident(object) 
|| ' INCREMENT BY ' || sq_increment_by
|| ' MINVALUE ' || sq_min_value 
|| ' MAXVALUE ' || sq_max_value
|| ' START WITH '   || sq_start_value
|| ' RESTART '  || sq_min_value 
|| ' CACHE '|| sq_cache_value 
|| sq_cycled || ' ;' ;

buffer := quote_ident(dest_schema) || '.' || quote_ident(object);
IF include_recs 
THEN
EXECUTE 'SELECT setval( ''' || buffer || ''', ' || sq_last_value || 
', ' || sq_is_called || ');' ; 
ELSE
EXECUTE 'SELECT setval( ''' || buffer || ''', ' || sq_start_value 
|| ', ' || sq_is_called || ');' ;
END IF;

  -- add sequence comments
SELECT oid INTO tbl_oid
  FROM pg_class 
 WHERE relkind = 'S'
   AND relnamespace = src_oid
   AND relname = quote_ident(object);

SELECT description INTO v_def
  FROM pg_description
 WHERE objoid = tbl_oid
   AND objsubid = 0;

IF FOUND
  THEN  
  

Re: [GENERAL] clone_schema function

2017-02-14 Thread Michael Librodo <mike.librodo(at)gmail(dot)com>

I had to modify the portion that copies FK constraint:

https://gist.github.com/mlibrodo/6f246c483e650dc716eba752a9d3c79a

Basically, the issue on my end was that the FK constraints on the 
cloned(destination) schema seem to reference the source_schema




--
Sent via pgsql-general mailing list (pgsql-general@postgresql.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-general


Re: [GENERAL] clone_schema function

2015-10-23 Thread Predrag Maric
The script is generating foreign keys which reference tables in the source
schema.
I had to change

219SELECT 'ALTER TABLE ' || quote_ident(dest_schema) || '.' ||
quote_ident(rn.relname)
220  || ' ADD CONSTRAINT ' ||
quote_ident(ct.conname) || ' ' || pg_get_constraintdef(ct.oid) || ';'

to

219SELECT 'ALTER TABLE ' || quote_ident(dest_schema) || '.' ||
quote_ident(rn.relname)
220 || ' ADD CONSTRAINT ' ||
quote_ident(ct.conname) || ' ' || replace(pg_get_constraintdef(ct.oid),
quote_ident(source_schema) || '.', quote_ident(dest_schema) || '.') || ';'

I'm attaching the updated script.
-- Function: clone_schema(text, text, boolean)

-- DROP FUNCTION clone_schema(text, text, boolean);

CREATE OR REPLACE FUNCTION clone_schema(
source_schema text,
dest_schema text,
include_recs boolean)
  RETURNS void AS
$BODY$
--  Initial code by Emanuel '3manuek' 
--  Last revision 2015-09-20 by Melvin Davidson
--  This function will clone all sequences, tables, indexes, rules, triggers, 
--  data(optional), views & functions from any existing schema to a new schema
-- SAMPLE CALL:
-- SELECT clone_schema('public', 'new_schema', TRUE);

DECLARE
  src_oid  oid;
  tbl_oid  oid;
  func_oid oid;
  con_oid  oid;
  v_path   text;
  v_func   text;
  v_args   text;
  v_connametext;
  v_rule   text;
  v_trig   text;
  object   text;
  buffer   text;
  srctbl   text;
  default_ text;
  v_column text;
  qry  text;
  dest_qry text;
  v_deftext;
  v_stat   integer;
  seqval   bigint;
  sq_last_valuebigint;
  sq_max_value bigint;
  sq_start_value   bigint;
  sq_increment_by  bigint;
  sq_min_value bigint;
  sq_cache_value   bigint;
  sq_log_cnt   bigint;
  sq_is_called boolean;
  sq_is_cycled boolean;
  sq_cycledchar(10);

BEGIN

-- Check that source_schema exists
  SELECT oid INTO src_oid
FROM pg_namespace
   WHERE nspname = quote_ident(source_schema);
  IF NOT FOUND
THEN 
RAISE NOTICE 'source schema % does not exist!', source_schema;
RETURN ;
  END IF;

  -- Check that dest_schema does not yet exist
  PERFORM nspname 
FROM pg_namespace
   WHERE nspname = quote_ident(dest_schema);
  IF FOUND
THEN 
RAISE NOTICE 'dest schema % already exists!', dest_schema;
RETURN ;
  END IF;

  EXECUTE 'CREATE SCHEMA ' || quote_ident(dest_schema) ;

  -- Add schema comment
  SELECT description INTO v_def
FROM pg_description
   WHERE objoid = src_oid
   AND objsubid = 0;
  IF FOUND 
THEN 
  EXECUTE 'COMMENT ON SCHEMA ' || quote_ident(dest_schema) || ' IS ' || 
quote_literal(v_def);
  END IF;
  
  -- Create sequences
  -- TODO: Find a way to make this sequence's owner is the correct table.
  FOR object IN
SELECT sequence_name::text 
  FROM information_schema.sequences
 WHERE sequence_schema = quote_ident(source_schema)
  LOOP
EXECUTE 'CREATE SEQUENCE ' || quote_ident(dest_schema) || '.' || 
quote_ident(object);
srctbl := quote_ident(source_schema) || '.' || quote_ident(object);

EXECUTE 'SELECT last_value, max_value, start_value, increment_by, 
min_value, cache_value, log_cnt, is_cycled, is_called 
  FROM ' || quote_ident(source_schema) || '.' || 
quote_ident(object) || ';' 
  INTO sq_last_value, sq_max_value, sq_start_value, 
sq_increment_by, sq_min_value, sq_cache_value, sq_log_cnt, sq_is_cycled, 
sq_is_called ; 

IF sq_is_cycled 
  THEN 
sq_cycled := 'CYCLE';
ELSE
sq_cycled := 'NO CYCLE';
END IF;

EXECUTE 'ALTER SEQUENCE '   || quote_ident(dest_schema) || '.' || 
quote_ident(object) 
|| ' INCREMENT BY ' || sq_increment_by
|| ' MINVALUE ' || sq_min_value 
|| ' MAXVALUE ' || sq_max_value
|| ' START WITH '   || sq_start_value
|| ' RESTART '  || sq_min_value 
|| ' CACHE '|| sq_cache_value 
|| sq_cycled || ' ;' ;

buffer := quote_ident(dest_schema) || '.' || quote_ident(object);
IF include_recs 
THEN
EXECUTE 'SELECT setval( ''' || buffer || ''', ' || sq_last_value || 
', ' || sq_is_called || ');' ; 
ELSE
EXECUTE 'SELECT setval( ''' || buffer || ''', ' || sq_start_value 
|| ', ' || sq_is_called || ');' ;
END IF;

  -- add sequence comments
SELECT oid INTO tbl_oid
  FROM pg_class 
 WHERE relkind = 'S'
   AND relnamespace = src_oid
   AND relname = quote_ident(object);

SELECT description INTO v_def
  FROM pg_description
 WHERE objoid = tbl_oid
   AND objsubid = 0;

IF FOUND
  THEN  
EXECUTE 'COMMENT ON SEQUENCE ' || quote_ident(dest_schema) || '.' || 
quote_ident(object)
 || ' IS ''' || v_def || ''';';
END IF;


  END LOOP;

-- Create tables 
  

Re: [GENERAL] clone_schema function

2015-10-23 Thread Melvin Davidson
Good catch. Thank you very much!

On Fri, Oct 23, 2015 at 10:50 AM, Predrag Maric  wrote:

> The script is generating foreign keys which reference tables in the source
> schema.
> I had to change
>
> 219SELECT 'ALTER TABLE ' || quote_ident(dest_schema) || '.' ||
> quote_ident(rn.relname)
> 220  || ' ADD CONSTRAINT ' ||
> quote_ident(ct.conname) || ' ' || pg_get_constraintdef(ct.oid) || ';'
>
> to
>
> 219SELECT 'ALTER TABLE ' || quote_ident(dest_schema) || '.' ||
> quote_ident(rn.relname)
> 220 || ' ADD CONSTRAINT ' ||
> quote_ident(ct.conname) || ' ' || replace(pg_get_constraintdef(ct.oid),
> quote_ident(source_schema) || '.', quote_ident(dest_schema) || '.') || ';'
>
> I'm attaching the updated script.
>



-- 
*Melvin Davidson*
I reserve the right to fantasize.  Whether or not you
wish to share my fantasy is entirely up to you.


Re: [GENERAL] clone_schema function

2015-09-20 Thread Melvin Davidson
Additional revision to avoid duplicating RI_Constraint triggers.


On Fri, Sep 18, 2015 at 4:09 PM, Melvin Davidson <melvin6...@gmail.com>
wrote:

> Revised to add rules after all tables are create to avoid error where
> table referenced in rule was not created yet.
>
> Added copying of column statistics with thanks to Marc Mamin  for pointing
> that out.
>
>
> On Thu, Sep 17, 2015 at 12:06 PM, Marc Mamin <m.ma...@intershop.de> wrote:
>
>>
>> --
>> *Von:* Melvin Davidson [melvin6...@gmail.com]
>> *Gesendet:* Donnerstag, 17. September 2015 17:11
>> *An:* Marc Mamin
>> *Cc:* pgsql-general@postgresql.org
>> *Betreff:* Re: [GENERAL] clone_schema function
>>
>> Thanks,
>>
>> >I'm not sure why you had trouble with the REPLACE(), as I did extensive
>> testing and it was working as coded.
>>
>> might be that my modification is required when ( and only when ?) the
>> source_schema is not part of the current search_path.
>> This is just a guess, I only gave your code a quick try ...
>>
>> >As for SET STATISTICS, I'm guessing that is a glitch in the CREATE TABLE
>>  LIKE option.
>> Yes, we can see it as an incomplete feature.
>>
>> regards,
>>
>> Marc Mamin
>>
>> On Thu, Sep 17, 2015 at 11:05 AM, Marc Mamin <m.ma...@intershop.de>
>> wrote:
>>
>>> Hello,
>>>
>>> I had to make 2 changes to get it running:
>>>
>>>
>>>
>>> line 193:
>>>
>>> -  REPLACE(column_default::text, quote_ident(source_schema) || '.',
>>> quote_ident(dest_schema || '.') )
>>>
>>> + REPLACE(column_default::text, quote_ident(source_schema) || '.',
>>> quote_ident(dest_schema) || '.' )
>>>
>>>
>>>
>>> line 319
>>>
>>> -  SELECT replace(v_def, ' ON ', ' ON ' || quote_ident(dest_schema) ||
>>> '.') INTO dest_qry;
>>>
>>> + SELECT replace(v_def, ' ON ' || quote_ident(source_schema), ' ON ' ||
>>> quote_ident(dest_schema) ) INTO dest_qry;
>>>
>>>
>>>
>>>
>>>
>>> moreover, you don't take care of the column statistic targets
>>>
>>> (i.e. ALTER TABLE t ALTER COLUMN c SET STATISTICS n;)
>>>
>>>
>>>
>>>
>>>
>>> regards,
>>>
>>>
>>>
>>> Marc Mamin
>>>
>>>
>>>
>>>
>>>
>>> *From:* pgsql-general-ow...@postgresql.org [mailto:
>>> pgsql-general-ow...@postgresql.org] *On Behalf Of *Melvin Davidson
>>> *Sent:* Donnerstag, 17. September 2015 15:48
>>> *To:* David G. Johnston
>>> *Cc:* Igor Neyman; Jim Nasby; Daniel Verite;
>>> pgsql-general@postgresql.org
>>> *Subject:* Re: [GENERAL] clone_schema function
>>>
>>>
>>>
>>> Attached is hopefully the final version of
>>>
>>>  FUNCTION clone_schema(text, text, boolean)
>>>
>>>  This function now does the following:
>>>  1. Checks that the source schema exists and the destination does not.
>>>  2. Creates the destination schema
>>>  3. Copies all sequences, tables, indexes, rules, triggers,
>>> data(optional),
>>>  views & functions from the source schema to the destination schema
>>>  4. Optionally copies records from source schema tables to destination
>>> tabled. (boolean)
>>>  5. Copies comments for source schema and all sequences, tables,
>>> functions, rules   and triggers;
>>>
>>>  If you discover a problem with this function, then kindly advise me
>>> what it is
>>>  and attach a script (SQL dump) to duplicate it. If you also have a fix,
>>> that is
>>>  even better.
>>>
>>>  However, if you "think" there is a problem that occurs when
>>>  A. The moon is full
>>>  B. You have blood type A/B negative
>>>  C. You have a table the same name as your database and schema
>>>  D. All you tables have column "id" in them
>>>  E. You've had 16 beers and 4 oxycodones
>>>  F. Your meth supplier raised the price
>>>
>>>  then do not contact me. Instead, run, do not walk,  immediately to your
>>>  psychologist, as you have serious issues in addition to database design
>>> problems
>>>  and you should not use this function under any circumstance.
>>>
>>>  CAVEAT EMPTOR!
>>>  The only known problem with this script is if functions in the

Re: [GENERAL] clone_schema function

2015-09-18 Thread Melvin Davidson
Revised to add rules after all tables are create to avoid error where table
referenced in rule was not created yet.

Added copying of column statistics with thanks to Marc Mamin  for pointing
that out.


On Thu, Sep 17, 2015 at 12:06 PM, Marc Mamin <m.ma...@intershop.de> wrote:

>
> --
> *Von:* Melvin Davidson [melvin6...@gmail.com]
> *Gesendet:* Donnerstag, 17. September 2015 17:11
> *An:* Marc Mamin
> *Cc:* pgsql-general@postgresql.org
> *Betreff:* Re: [GENERAL] clone_schema function
>
> Thanks,
>
> >I'm not sure why you had trouble with the REPLACE(), as I did extensive
> testing and it was working as coded.
>
> might be that my modification is required when ( and only when ?) the
> source_schema is not part of the current search_path.
> This is just a guess, I only gave your code a quick try ...
>
> >As for SET STATISTICS, I'm guessing that is a glitch in the CREATE TABLE
>  LIKE option.
> Yes, we can see it as an incomplete feature.
>
> regards,
>
> Marc Mamin
>
> On Thu, Sep 17, 2015 at 11:05 AM, Marc Mamin <m.ma...@intershop.de> wrote:
>
>> Hello,
>>
>> I had to make 2 changes to get it running:
>>
>>
>>
>> line 193:
>>
>> -  REPLACE(column_default::text, quote_ident(source_schema) || '.',
>> quote_ident(dest_schema || '.') )
>>
>> + REPLACE(column_default::text, quote_ident(source_schema) || '.',
>> quote_ident(dest_schema) || '.' )
>>
>>
>>
>> line 319
>>
>> -  SELECT replace(v_def, ' ON ', ' ON ' || quote_ident(dest_schema) ||
>> '.') INTO dest_qry;
>>
>> + SELECT replace(v_def, ' ON ' || quote_ident(source_schema), ' ON ' ||
>> quote_ident(dest_schema) ) INTO dest_qry;
>>
>>
>>
>>
>>
>> moreover, you don't take care of the column statistic targets
>>
>> (i.e. ALTER TABLE t ALTER COLUMN c SET STATISTICS n;)
>>
>>
>>
>>
>>
>> regards,
>>
>>
>>
>> Marc Mamin
>>
>>
>>
>>
>>
>> *From:* pgsql-general-ow...@postgresql.org [mailto:
>> pgsql-general-ow...@postgresql.org] *On Behalf Of *Melvin Davidson
>> *Sent:* Donnerstag, 17. September 2015 15:48
>> *To:* David G. Johnston
>> *Cc:* Igor Neyman; Jim Nasby; Daniel Verite; pgsql-general@postgresql.org
>> *Subject:* Re: [GENERAL] clone_schema function
>>
>>
>>
>> Attached is hopefully the final version of
>>
>>  FUNCTION clone_schema(text, text, boolean)
>>
>>  This function now does the following:
>>  1. Checks that the source schema exists and the destination does not.
>>  2. Creates the destination schema
>>  3. Copies all sequences, tables, indexes, rules, triggers,
>> data(optional),
>>  views & functions from the source schema to the destination schema
>>  4. Optionally copies records from source schema tables to destination
>> tabled. (boolean)
>>  5. Copies comments for source schema and all sequences, tables,
>> functions, rules   and triggers;
>>
>>  If you discover a problem with this function, then kindly advise me what
>> it is
>>  and attach a script (SQL dump) to duplicate it. If you also have a fix,
>> that is
>>  even better.
>>
>>  However, if you "think" there is a problem that occurs when
>>  A. The moon is full
>>  B. You have blood type A/B negative
>>  C. You have a table the same name as your database and schema
>>  D. All you tables have column "id" in them
>>  E. You've had 16 beers and 4 oxycodones
>>  F. Your meth supplier raised the price
>>
>>  then do not contact me. Instead, run, do not walk,  immediately to your
>>  psychologist, as you have serious issues in addition to database design
>> problems
>>  and you should not use this function under any circumstance.
>>
>>  CAVEAT EMPTOR!
>>  The only known problem with this script is if functions in the source
>> schema
>>  have a SELECT using the form of tablename.columm, and tablename is the
>> same
>>  as  source schema, then tablename will be changed to destination schema
>> name.
>>  However, since good developers and DBA's use the form of alias.column,
>> this
>>  should rarely be a problem.
>>
>>
>>
>> On Tue, Sep 15, 2015 at 12:37 PM, Melvin Davidson <melvin6...@gmail.com>
>> wrote:
>>
>> David,
>>
>> Yes, it would be nice, but
>>
>> 1. I am still working also on bringing over the comments for various
>> objects
>>
>> 2. What you request is c

Re: [GENERAL] clone_schema function

2015-09-17 Thread Marc Mamin


Von: Melvin Davidson [melvin6...@gmail.com]
Gesendet: Donnerstag, 17. September 2015 17:11
An: Marc Mamin
Cc: pgsql-general@postgresql.org
Betreff: Re: [GENERAL] clone_schema function

Thanks,

>I'm not sure why you had trouble with the REPLACE(), as I did extensive 
>testing and it was working as coded.

might be that my modification is required when ( and only when ?) the 
source_schema is not part of the current search_path.
This is just a guess, I only gave your code a quick try ...

>As for SET STATISTICS, I'm guessing that is a glitch in the CREATE TABLE  
>LIKE option.
Yes, we can see it as an incomplete feature.

regards,

Marc Mamin

On Thu, Sep 17, 2015 at 11:05 AM, Marc Mamin 
<m.ma...@intershop.de<mailto:m.ma...@intershop.de>> wrote:
Hello,
I had to make 2 changes to get it running:

line 193:
-  REPLACE(column_default::text, quote_ident(source_schema) || '.', 
quote_ident(dest_schema || '.') )
+ REPLACE(column_default::text, quote_ident(source_schema) || '.', 
quote_ident(dest_schema) || '.' )

line 319
-  SELECT replace(v_def, ' ON ', ' ON ' || quote_ident(dest_schema) || '.') 
INTO dest_qry;
+ SELECT replace(v_def, ' ON ' || quote_ident(source_schema), ' ON ' || 
quote_ident(dest_schema) ) INTO dest_qry;


moreover, you don't take care of the column statistic targets
(i.e. ALTER TABLE t ALTER COLUMN c SET STATISTICS n;)


regards,

Marc Mamin


From: 
pgsql-general-ow...@postgresql.org<mailto:pgsql-general-ow...@postgresql.org> 
[mailto:pgsql-general-ow...@postgresql.org<mailto:pgsql-general-ow...@postgresql.org>]
 On Behalf Of Melvin Davidson
Sent: Donnerstag, 17. September 2015 15:48
To: David G. Johnston
Cc: Igor Neyman; Jim Nasby; Daniel Verite; 
pgsql-general@postgresql.org<mailto:pgsql-general@postgresql.org>
Subject: Re: [GENERAL] clone_schema function

Attached is hopefully the final version of

 FUNCTION clone_schema(text, text, boolean)

 This function now does the following:
 1. Checks that the source schema exists and the destination does not.
 2. Creates the destination schema
 3. Copies all sequences, tables, indexes, rules, triggers, data(optional),
 views & functions from the source schema to the destination schema
 4. Optionally copies records from source schema tables to destination tabled. 
(boolean)
 5. Copies comments for source schema and all sequences, tables, functions, 
rules   and triggers;

 If you discover a problem with this function, then kindly advise me what it is
 and attach a script (SQL dump) to duplicate it. If you also have a fix, that is
 even better.

 However, if you "think" there is a problem that occurs when
 A. The moon is full
 B. You have blood type A/B negative
 C. You have a table the same name as your database and schema
 D. All you tables have column "id" in them
 E. You've had 16 beers and 4 oxycodones
 F. Your meth supplier raised the price

 then do not contact me. Instead, run, do not walk,  immediately to your
 psychologist, as you have serious issues in addition to database design 
problems
 and you should not use this function under any circumstance.

 CAVEAT EMPTOR!
 The only known problem with this script is if functions in the source schema
 have a SELECT using the form of tablename.columm, and tablename is the same
 as  source schema, then tablename will be changed to destination schema name.
 However, since good developers and DBA's use the form of alias.column, this
 should rarely be a problem.

On Tue, Sep 15, 2015 at 12:37 PM, Melvin Davidson 
<melvin6...@gmail.com<mailto:melvin6...@gmail.com>> wrote:
David,

Yes, it would be nice, but
1. I am still working also on bringing over the comments for various objects
2. What you request is currently beyond my capability. Not to mention that 
there already
are existing tools that do that, albeit they are not free.

On Tue, Sep 15, 2015 at 12:27 PM, David G. Johnston 
<david.g.johns...@gmail.com<mailto:david.g.johns...@gmail.com>> wrote:
To make the casual user's life easier, in the face of this reality, it would 
nice if the routine would generate a reasonably attempted "diff" between the 
two so that all changes can be reviewed in a structured manner aided by 
correctly configured tools and advice.

On Tue, Sep 15, 2015 at 12:20 PM, Melvin Davidson 
<melvin6...@gmail.com<mailto:melvin6...@gmail.com>> wrote:
Igor,
I understand your point, however, I have spent over a week making a function
that previously did very little do a lot.
Naming a table the same as a schema is a very silly idea.
Unless you care to take the time to provide a full
schema, and function that fails for reasonable , practical design
I will ignore all further comments.

On Tue, Sep 15, 2015 at 9:55 AM, Igor Neyman 
<iney...@perceptron.com<mailto:iney...@perceptron.com>> wrote:

That is correct. But table old will NOT be converted to new becau

Re: [GENERAL] clone_schema function

2015-09-17 Thread Melvin Davidson
Attached is hopefully the final version of
 FUNCTION clone_schema(text, text, boolean)

 This function now does the following:
 1. Checks that the source schema exists and the destination does not.
 2. Creates the destination schema
 3. Copies all sequences, tables, indexes, rules, triggers, data(optional),
 views & functions from the source schema to the destination schema
 4. Optionally copies records from source schema tables to destination
tabled. (boolean)
 5. Copies comments for source schema and all sequences, tables, functions,
rules   and triggers;

 If you discover a problem with this function, then kindly advise me what
it is
 and attach a script (SQL dump) to duplicate it. If you also have a fix,
that is
 even better.

 However, if you "think" there is a problem that occurs when
 A. The moon is full
 B. You have blood type A/B negative
 C. You have a table the same name as your database and schema
 D. All you tables have column "id" in them
 E. You've had 16 beers and 4 oxycodones
 F. Your meth supplier raised the price

 then do not contact me. Instead, run, do not walk,  immediately to your
 psychologist, as you have serious issues in addition to database design
problems
 and you should not use this function under any circumstance.

 CAVEAT EMPTOR!
 The only known problem with this script is if functions in the source
schema
 have a SELECT using the form of tablename.columm, and tablename is the
same
 as  source schema, then tablename will be changed to destination schema
name.
 However, since good developers and DBA's use the form of alias.column,
this
 should rarely be a problem.

On Tue, Sep 15, 2015 at 12:37 PM, Melvin Davidson 
wrote:

> David,
>
> Yes, it would be nice, but
> 1. I am still working also on bringing over the comments for various
> objects
> 2. What you request is currently beyond my capability. Not to mention that
> there already
> are existing tools that do that, albeit they are not free.
>
> On Tue, Sep 15, 2015 at 12:27 PM, David G. Johnston <
> david.g.johns...@gmail.com> wrote:
>
>> To make the casual user's life easier, in the face of this reality, it
>> would nice if the routine would generate a reasonably attempted "diff"
>> between the two so that all changes can be reviewed in a structured manner
>> aided by correctly configured tools and advice.
>>
>> On Tue, Sep 15, 2015 at 12:20 PM, Melvin Davidson 
>> wrote:
>>
>>> Igor,
>>> I understand your point, however, I have spent over a week making a
>>> function
>>> that previously did very little do a lot.
>>> Naming a table the same as a schema is a very silly idea.
>>>
>>> Unless you care to take the time to provide a full
>>> schema, and function that fails for reasonable , practical design
>>> I will ignore all further comments.
>>>
>>> On Tue, Sep 15, 2015 at 9:55 AM, Igor Neyman 
>>> wrote:
>>>


 That is correct. But table old will NOT be converted to new because

 only the schema name is converted. And table "old" WILL exist because
 it will also be copied.

 I have tested and it works properly.

 Please do not provide hypothetical examples. Give me an actual working
 example that causes the problem.

 This statement:

 SELECT old.field FROM old.old;

 selects column “field” from table “old” which is in schema “old”.

 Your script converts it into:

 SELECT new.field FROM new.old

 which will try to select column “field” from table “old” in schema
 “new”.



 Again:

 SELECT new.field

 means select column “field” from table “new”, which does not exists.

 Not sure, what other example you need.

 Regards,

 Igor Neyman


>>>
>>>
>>> --
>>> *Melvin Davidson*
>>> I reserve the right to fantasize.  Whether or not you
>>> wish to share my fantasy is entirely up to you.
>>>
>>
>>
>
>
> --
> *Melvin Davidson*
> I reserve the right to fantasize.  Whether or not you
> wish to share my fantasy is entirely up to you.
>



-- 
*Melvin Davidson*
I reserve the right to fantasize.  Whether or not you
wish to share my fantasy is entirely up to you.


clone_schema.sql
Description: Binary data

-- 
Sent via pgsql-general mailing list (pgsql-general@postgresql.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-general


Re: [GENERAL] clone_schema function

2015-09-17 Thread Marc Mamin
Hello,
I had to make 2 changes to get it running:

line 193:
-  REPLACE(column_default::text, quote_ident(source_schema) || '.', 
quote_ident(dest_schema || '.') )
+ REPLACE(column_default::text, quote_ident(source_schema) || '.', 
quote_ident(dest_schema) || '.' )

line 319
-  SELECT replace(v_def, ' ON ', ' ON ' || quote_ident(dest_schema) || '.') 
INTO dest_qry;
+ SELECT replace(v_def, ' ON ' || quote_ident(source_schema), ' ON ' || 
quote_ident(dest_schema) ) INTO dest_qry;


moreover, you don't take care of the column statistic targets
(i.e. ALTER TABLE t ALTER COLUMN c SET STATISTICS n;)


regards,

Marc Mamin


From: pgsql-general-ow...@postgresql.org 
[mailto:pgsql-general-ow...@postgresql.org] On Behalf Of Melvin Davidson
Sent: Donnerstag, 17. September 2015 15:48
To: David G. Johnston
Cc: Igor Neyman; Jim Nasby; Daniel Verite; pgsql-general@postgresql.org
Subject: Re: [GENERAL] clone_schema function

Attached is hopefully the final version of
 FUNCTION clone_schema(text, text, boolean)

 This function now does the following:
 1. Checks that the source schema exists and the destination does not.
 2. Creates the destination schema
 3. Copies all sequences, tables, indexes, rules, triggers, data(optional),
 views & functions from the source schema to the destination schema
 4. Optionally copies records from source schema tables to destination tabled. 
(boolean)
 5. Copies comments for source schema and all sequences, tables, functions, 
rules   and triggers;

 If you discover a problem with this function, then kindly advise me what it is
 and attach a script (SQL dump) to duplicate it. If you also have a fix, that is
 even better.

 However, if you "think" there is a problem that occurs when
 A. The moon is full
 B. You have blood type A/B negative
 C. You have a table the same name as your database and schema
 D. All you tables have column "id" in them
 E. You've had 16 beers and 4 oxycodones
 F. Your meth supplier raised the price

 then do not contact me. Instead, run, do not walk,  immediately to your
 psychologist, as you have serious issues in addition to database design 
problems
 and you should not use this function under any circumstance.

 CAVEAT EMPTOR!
 The only known problem with this script is if functions in the source schema
 have a SELECT using the form of tablename.columm, and tablename is the same
 as  source schema, then tablename will be changed to destination schema name.
 However, since good developers and DBA's use the form of alias.column, this
 should rarely be a problem.

On Tue, Sep 15, 2015 at 12:37 PM, Melvin Davidson 
<melvin6...@gmail.com<mailto:melvin6...@gmail.com>> wrote:
David,

Yes, it would be nice, but
1. I am still working also on bringing over the comments for various objects
2. What you request is currently beyond my capability. Not to mention that 
there already
are existing tools that do that, albeit they are not free.

On Tue, Sep 15, 2015 at 12:27 PM, David G. Johnston 
<david.g.johns...@gmail.com<mailto:david.g.johns...@gmail.com>> wrote:
To make the casual user's life easier, in the face of this reality, it would 
nice if the routine would generate a reasonably attempted "diff" between the 
two so that all changes can be reviewed in a structured manner aided by 
correctly configured tools and advice.

On Tue, Sep 15, 2015 at 12:20 PM, Melvin Davidson 
<melvin6...@gmail.com<mailto:melvin6...@gmail.com>> wrote:
Igor,
I understand your point, however, I have spent over a week making a function
that previously did very little do a lot.
Naming a table the same as a schema is a very silly idea.
Unless you care to take the time to provide a full
schema, and function that fails for reasonable , practical design
I will ignore all further comments.

On Tue, Sep 15, 2015 at 9:55 AM, Igor Neyman 
<iney...@perceptron.com<mailto:iney...@perceptron.com>> wrote:

That is correct. But table old will NOT be converted to new because
only the schema name is converted. And table "old" WILL exist because it will 
also be copied.
I have tested and it works properly.
Please do not provide hypothetical examples. Give me an actual working example 
that causes the problem.
This statement:
SELECT old.field FROM old.old;
selects column “field” from table “old” which is in schema “old”.
Your script converts it into:
SELECT new.field FROM new.old
which will try to select column “field” from table “old” in schema “new”.

Again:
SELECT new.field
means select column “field” from table “new”, which does not exists.
Not sure, what other example you need.
Regards,
Igor Neyman



--
Melvin Davidson
I reserve the right to fantasize.  Whether or not you
wish to share my fantasy is entirely up to you. 
[http://us.i1.yimg.com/us.yimg.com/i/mesg/tsmileys2/01.gif]




--
Melvin Davidson
I reserve the right to fantasize.  Whether or not you
wish to share my fantasy is entirely up to you. 

Re: [GENERAL] clone_schema function

2015-09-17 Thread Melvin Davidson
Thanks,

I'm not sure why you had trouble with the REPLACE(), as I did extensive
testing and it was working as coded.

As for SET STATISTICS, I'm guessing that is a glitch in the CREATE TABLE
 LIKE option.

On Thu, Sep 17, 2015 at 11:05 AM, Marc Mamin <m.ma...@intershop.de> wrote:

> Hello,
>
> I had to make 2 changes to get it running:
>
>
>
> line 193:
>
> -  REPLACE(column_default::text, quote_ident(source_schema) || '.',
> quote_ident(dest_schema || '.') )
>
> + REPLACE(column_default::text, quote_ident(source_schema) || '.',
> quote_ident(dest_schema) || '.' )
>
>
>
> line 319
>
> -  SELECT replace(v_def, ' ON ', ' ON ' || quote_ident(dest_schema) ||
> '.') INTO dest_qry;
>
> + SELECT replace(v_def, ' ON ' || quote_ident(source_schema), ' ON ' ||
> quote_ident(dest_schema) ) INTO dest_qry;
>
>
>
>
>
> moreover, you don't take care of the column statistic targets
>
> (i.e. ALTER TABLE t ALTER COLUMN c SET STATISTICS n;)
>
>
>
>
>
> regards,
>
>
>
> Marc Mamin
>
>
>
>
>
> *From:* pgsql-general-ow...@postgresql.org [mailto:
> pgsql-general-ow...@postgresql.org] *On Behalf Of *Melvin Davidson
> *Sent:* Donnerstag, 17. September 2015 15:48
> *To:* David G. Johnston
> *Cc:* Igor Neyman; Jim Nasby; Daniel Verite; pgsql-general@postgresql.org
> *Subject:* Re: [GENERAL] clone_schema function
>
>
>
> Attached is hopefully the final version of
>
>  FUNCTION clone_schema(text, text, boolean)
>
>  This function now does the following:
>  1. Checks that the source schema exists and the destination does not.
>  2. Creates the destination schema
>  3. Copies all sequences, tables, indexes, rules, triggers,
> data(optional),
>  views & functions from the source schema to the destination schema
>  4. Optionally copies records from source schema tables to destination
> tabled. (boolean)
>  5. Copies comments for source schema and all sequences, tables,
> functions, rules   and triggers;
>
>  If you discover a problem with this function, then kindly advise me what
> it is
>  and attach a script (SQL dump) to duplicate it. If you also have a fix,
> that is
>  even better.
>
>  However, if you "think" there is a problem that occurs when
>  A. The moon is full
>  B. You have blood type A/B negative
>  C. You have a table the same name as your database and schema
>  D. All you tables have column "id" in them
>  E. You've had 16 beers and 4 oxycodones
>  F. Your meth supplier raised the price
>
>  then do not contact me. Instead, run, do not walk,  immediately to your
>  psychologist, as you have serious issues in addition to database design
> problems
>  and you should not use this function under any circumstance.
>
>  CAVEAT EMPTOR!
>  The only known problem with this script is if functions in the source
> schema
>  have a SELECT using the form of tablename.columm, and tablename is the
> same
>  as  source schema, then tablename will be changed to destination schema
> name.
>  However, since good developers and DBA's use the form of alias.column,
> this
>  should rarely be a problem.
>
>
>
> On Tue, Sep 15, 2015 at 12:37 PM, Melvin Davidson <melvin6...@gmail.com>
> wrote:
>
> David,
>
> Yes, it would be nice, but
>
> 1. I am still working also on bringing over the comments for various
> objects
>
> 2. What you request is currently beyond my capability. Not to mention that
> there already
>
> are existing tools that do that, albeit they are not free.
>
>
>
> On Tue, Sep 15, 2015 at 12:27 PM, David G. Johnston <
> david.g.johns...@gmail.com> wrote:
>
> To make the casual user's life easier, in the face of this reality, it
> would nice if the routine would generate a reasonably attempted "diff"
> between the two so that all changes can be reviewed in a structured manner
> aided by correctly configured tools and advice.
>
>
>
> On Tue, Sep 15, 2015 at 12:20 PM, Melvin Davidson <melvin6...@gmail.com>
> wrote:
>
> Igor,
> I understand your point, however, I have spent over a week making a
> function
> that previously did very little do a lot.
>
> Naming a table the same as a schema is a very silly idea.
>
> Unless you care to take the time to provide a full
>
> schema, and function that fails for reasonable , practical design
>
> I will ignore all further comments.
>
>
>
> On Tue, Sep 15, 2015 at 9:55 AM, Igor Neyman <iney...@perceptron.com>
> wrote:
>
>
>
> That is correct. But table old will NOT be converted to new because
>
> only the schema name is converted. And table "old" WILL e

Re: [GENERAL] clone_schema function

2015-09-15 Thread Jim Nasby

On 9/14/15 8:02 PM, Melvin Davidson wrote:

Actually, on further thought, you example shows that it works correctly
because we do want all references to the old schema to be changed to the
new schema, since all copies of functions will now reside in the new
schema. Otherwise, there is no point of duplicating those functions.


Read my example again:

  SELECT old.field FROM old.old;

That will end up as

  SELECT new.field FROM new.old

Which will give you this error:

ERROR:  missing FROM-clause entry for table "new"
LINE 1: SELECT new.field FROM new.old;

Even if you could fix that, there's yet more problems you'll run into, 
like if someone has a plpgsql block with the same name as the old schema.


I'm not trying to denigrate the work you and others have put into this 
script, but everyone should be aware that it's impossible to create a 
robust solution without a parser. Unfortunately, you could end up with a 
function that still compiles but does something rather different after 
the move. That makes the script potentially dangerous (granted, the odds 
of this are pretty low).


One thing I think would be very interesting is a parser that preserves 
whitespace and comments. That would allow us to store a parsed version 
of (at least plpgsql and sql) functions. The same technique would also 
be handy for views. This would allow a lot (all?) other renames to 
propagate to functions instead of breaking them (as currently happens).


Another option is supporting some kind of official way to specially 
designate database objects in any procedure language (ie, the @schema@ 
syntax that extensions use). That would make it possible to rename 
properly written functions without adverse side effects.

--
Jim Nasby, Data Architect, Blue Treble Consulting, Austin TX
Experts in Analytics, Data Architecture and PostgreSQL
Data in Trouble? Get it in Treble! http://BlueTreble.com


--
Sent via pgsql-general mailing list (pgsql-general@postgresql.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-general


Re: [GENERAL] clone_schema function

2015-09-15 Thread Melvin Davidson
Igor,
I understand your point, however, I have spent over a week making a
function
that previously did very little do a lot.
Naming a table the same as a schema is a very silly idea.

Unless you care to take the time to provide a full
schema, and function that fails for reasonable , practical design
I will ignore all further comments.

On Tue, Sep 15, 2015 at 9:55 AM, Igor Neyman  wrote:

>
>
> That is correct. But table old will NOT be converted to new because
>
> only the schema name is converted. And table "old" WILL exist because it
> will also be copied.
>
> I have tested and it works properly.
>
> Please do not provide hypothetical examples. Give me an actual working
> example that causes the problem.
>
> This statement:
>
> SELECT old.field FROM old.old;
>
> selects column “field” from table “old” which is in schema “old”.
>
> Your script converts it into:
>
> SELECT new.field FROM new.old
>
> which will try to select column “field” from table “old” in schema “new”.
>
>
>
> Again:
>
> SELECT new.field
>
> means select column “field” from table “new”, which does not exists.
>
> Not sure, what other example you need.
>
> Regards,
>
> Igor Neyman
>
>


-- 
*Melvin Davidson*
I reserve the right to fantasize.  Whether or not you
wish to share my fantasy is entirely up to you.


Re: [GENERAL] clone_schema function

2015-09-15 Thread David G. Johnston
To make the casual user's life easier, in the face of this reality, it
would nice if the routine would generate a reasonably attempted "diff"
between the two so that all changes can be reviewed in a structured manner
aided by correctly configured tools and advice.

On Tue, Sep 15, 2015 at 12:20 PM, Melvin Davidson 
wrote:

> Igor,
> I understand your point, however, I have spent over a week making a
> function
> that previously did very little do a lot.
> Naming a table the same as a schema is a very silly idea.
>
> Unless you care to take the time to provide a full
> schema, and function that fails for reasonable , practical design
> I will ignore all further comments.
>
> On Tue, Sep 15, 2015 at 9:55 AM, Igor Neyman 
> wrote:
>
>>
>>
>> That is correct. But table old will NOT be converted to new because
>>
>> only the schema name is converted. And table "old" WILL exist because it
>> will also be copied.
>>
>> I have tested and it works properly.
>>
>> Please do not provide hypothetical examples. Give me an actual working
>> example that causes the problem.
>>
>> This statement:
>>
>> SELECT old.field FROM old.old;
>>
>> selects column “field” from table “old” which is in schema “old”.
>>
>> Your script converts it into:
>>
>> SELECT new.field FROM new.old
>>
>> which will try to select column “field” from table “old” in schema “new”.
>>
>>
>>
>> Again:
>>
>> SELECT new.field
>>
>> means select column “field” from table “new”, which does not exists.
>>
>> Not sure, what other example you need.
>>
>> Regards,
>>
>> Igor Neyman
>>
>>
>
>
> --
> *Melvin Davidson*
> I reserve the right to fantasize.  Whether or not you
> wish to share my fantasy is entirely up to you.
>


Re: [GENERAL] clone_schema function

2015-09-15 Thread Igor Neyman

That is correct. But table old will NOT be converted to new because
only the schema name is converted. And table "old" WILL exist because it will 
also be copied.
I have tested and it works properly.
Please do not provide hypothetical examples. Give me an actual working example 
that causes the problem.
This statement:
SELECT old.field FROM old.old;
selects column “field” from table “old” which is in schema “old”.
Your script converts it into:
SELECT new.field FROM new.old
which will try to select column “field” from table “old” in schema “new”.

Again:
SELECT new.field
means select column “field” from table “new”, which does not exists.
Not sure, what other example you need.
Regards,
Igor Neyman


Re: [GENERAL] clone_schema function

2015-09-15 Thread Igor Neyman
I still do not see any problem. The whole purpose of the function is to copy 
ALL sequences , tables and functions to "new" schema, so new.old WILL exist.

I don't see how you can possibly write a function that references a schema that 
does not yet exist!

Again, please provide a _working_ example of what you think the problem is.

Melvin,

This statement:

SELECT old.field FROM old.old;

selects column “field” from table “old” which is in schema “old”.

Your script converts it into:

SELECT new.field FROM new.old

which will try to select column “field” from table “new” in schema “new”.
The obvious problem is that there is no table “new” in schema “new”, the table 
will still be called “old”.

Jim’s example is very similar to what I provided a few days ago.

Regards,
Igor Neyman



Re: [GENERAL] clone_schema function

2015-09-15 Thread Melvin Davidson
David,

Yes, it would be nice, but
1. I am still working also on bringing over the comments for various objects
2. What you request is currently beyond my capability. Not to mention that
there already
are existing tools that do that, albeit they are not free.

On Tue, Sep 15, 2015 at 12:27 PM, David G. Johnston <
david.g.johns...@gmail.com> wrote:

> To make the casual user's life easier, in the face of this reality, it
> would nice if the routine would generate a reasonably attempted "diff"
> between the two so that all changes can be reviewed in a structured manner
> aided by correctly configured tools and advice.
>
> On Tue, Sep 15, 2015 at 12:20 PM, Melvin Davidson 
> wrote:
>
>> Igor,
>> I understand your point, however, I have spent over a week making a
>> function
>> that previously did very little do a lot.
>> Naming a table the same as a schema is a very silly idea.
>>
>> Unless you care to take the time to provide a full
>> schema, and function that fails for reasonable , practical design
>> I will ignore all further comments.
>>
>> On Tue, Sep 15, 2015 at 9:55 AM, Igor Neyman 
>> wrote:
>>
>>>
>>>
>>> That is correct. But table old will NOT be converted to new because
>>>
>>> only the schema name is converted. And table "old" WILL exist because it
>>> will also be copied.
>>>
>>> I have tested and it works properly.
>>>
>>> Please do not provide hypothetical examples. Give me an actual working
>>> example that causes the problem.
>>>
>>> This statement:
>>>
>>> SELECT old.field FROM old.old;
>>>
>>> selects column “field” from table “old” which is in schema “old”.
>>>
>>> Your script converts it into:
>>>
>>> SELECT new.field FROM new.old
>>>
>>> which will try to select column “field” from table “old” in schema
>>> “new”.
>>>
>>>
>>>
>>> Again:
>>>
>>> SELECT new.field
>>>
>>> means select column “field” from table “new”, which does not exists.
>>>
>>> Not sure, what other example you need.
>>>
>>> Regards,
>>>
>>> Igor Neyman
>>>
>>>
>>
>>
>> --
>> *Melvin Davidson*
>> I reserve the right to fantasize.  Whether or not you
>> wish to share my fantasy is entirely up to you.
>>
>
>


-- 
*Melvin Davidson*
I reserve the right to fantasize.  Whether or not you
wish to share my fantasy is entirely up to you.


Re: [GENERAL] clone_schema function

2015-09-15 Thread Melvin Davidson
That is correct. But table old will NOT be converted to new because
only the schema name is converted. And table "old" WILL exist because it
will also be copied.

I have tested and it works properly.

Please do not provide hypothetical examples. Give me an actual working
example that causes the problem.

On Tue, Sep 15, 2015 at 9:39 AM, Igor Neyman  wrote:

> I still do not see any problem. The whole purpose of the function is to
> copy ALL sequences , tables and functions to "new" schema, so new.old WILL
> exist.
>
>
> I don't see how you can possibly write a function that references a schema
> that does not yet exist!
>
> Again, please provide a _working_ example of what you think the problem is.
>
>
>
> Melvin,
>
>
>
> This statement:
>
>
>
> SELECT old.field FROM old.old;
>
>
>
> selects column “field” from table “old” which is in schema “old”.
>
>
>
> Your script converts it into:
>
>
>
> SELECT new.field FROM new.old
>
>
>
> which will try to select column “field” from table “new” in schema “new”.
>
> The obvious problem is that there is no table “new” in schema “new”, the
> table will still be called “old”.
>
>
>
> Jim’s example is very similar to what I provided a few days ago.
>
>
>
> Regards,
>
> Igor Neyman
>
>
>



-- 
*Melvin Davidson*
I reserve the right to fantasize.  Whether or not you
wish to share my fantasy is entirely up to you.


Re: [GENERAL] clone_schema function

2015-09-15 Thread Melvin Davidson
I still do not see any problem. The whole purpose of the function is to
copy ALL sequences , tables and functions to "new" schema, so new.old WILL
exist.

I don't see how you can possibly write a function that references a schema
that does not yet exist!

Again, please provide a _working_ example of what you think the problem is.



On Tue, Sep 15, 2015 at 3:22 AM, Jim Nasby  wrote:

> On 9/14/15 8:02 PM, Melvin Davidson wrote:
>
>> Actually, on further thought, you example shows that it works correctly
>> because we do want all references to the old schema to be changed to the
>> new schema, since all copies of functions will now reside in the new
>> schema. Otherwise, there is no point of duplicating those functions.
>>
>
> Read my example again:
>
>   SELECT old.field FROM old.old;
>
> That will end up as
>
>   SELECT new.field FROM new.old
>
> Which will give you this error:
>
> ERROR:  missing FROM-clause entry for table "new"
> LINE 1: SELECT new.field FROM new.old;
>
> Even if you could fix that, there's yet more problems you'll run into,
> like if someone has a plpgsql block with the same name as the old schema.
>
> I'm not trying to denigrate the work you and others have put into this
> script, but everyone should be aware that it's impossible to create a
> robust solution without a parser. Unfortunately, you could end up with a
> function that still compiles but does something rather different after the
> move. That makes the script potentially dangerous (granted, the odds of
> this are pretty low).
>
> One thing I think would be very interesting is a parser that preserves
> whitespace and comments. That would allow us to store a parsed version of
> (at least plpgsql and sql) functions. The same technique would also be
> handy for views. This would allow a lot (all?) other renames to propagate
> to functions instead of breaking them (as currently happens).
>
> Another option is supporting some kind of official way to specially
> designate database objects in any procedure language (ie, the @schema@
> syntax that extensions use). That would make it possible to rename properly
> written functions without adverse side effects.
>
> --
> Jim Nasby, Data Architect, Blue Treble Consulting, Austin TX
> Experts in Analytics, Data Architecture and PostgreSQL
> Data in Trouble? Get it in Treble! http://BlueTreble.com
>



-- 
*Melvin Davidson*
I reserve the right to fantasize.  Whether or not you
wish to share my fantasy is entirely up to you.


Re: [GENERAL] clone_schema function

2015-09-14 Thread Jim Nasby

On 9/12/15 9:38 AM, Daniel Verite wrote:

"seriously flawed" is a bit of a stretch. Most sane developers would not
>have schema names of one letter.
>They usually name a schema something practical, which totally avoids your
>nit picky exception.

That's confusing the example with the problem it shows.

Another example could be:
if the source schema is "public" and the function body contains
GRANT SELECT on sometable to public;
then this statement would be wrongly altered by replace().


Well, the new version actually fixes that. But you could still trip this 
up, certainly in the functions. IE:


CREATE FUNCTION ...
  SELECT old.field FROM old.old;

That will end up as

  SELECT new.field FROM new.old

which won't work.


My objection is not about some corner case: it's the general
idea of patching the entire body of a function without a fully-fledged
parser that is dead on arrival.


ISTM that's also the biggest blocker for allowing extensions that refer 
to other schemas to be relocatable. It would be interesting if we had 
some way to handle this inside function bodies, perhaps via something 
equivalent to @extschema@.

--
Jim Nasby, Data Architect, Blue Treble Consulting, Austin TX
Experts in Analytics, Data Architecture and PostgreSQL
Data in Trouble? Get it in Treble! http://BlueTreble.com


--
Sent via pgsql-general mailing list (pgsql-general@postgresql.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-general


Re: [GENERAL] clone_schema function

2015-09-14 Thread Melvin Davidson
Jim,

Have you actually tried this, or is it just a theory? AFAIK, the function
will work because only the schema name is changed.. So please provide
a full working example of a function that fails and I will attempt a
solution.

On Mon, Sep 14, 2015 at 6:36 PM, Jim Nasby  wrote:

> On 9/12/15 9:38 AM, Daniel Verite wrote:
>
>> "seriously flawed" is a bit of a stretch. Most sane developers would not
>>> >have schema names of one letter.
>>> >They usually name a schema something practical, which totally avoids
>>> your
>>> >nit picky exception.
>>>
>> That's confusing the example with the problem it shows.
>>
>> Another example could be:
>> if the source schema is "public" and the function body contains
>> GRANT SELECT on sometable to public;
>> then this statement would be wrongly altered by replace().
>>
>
> Well, the new version actually fixes that. But you could still trip this
> up, certainly in the functions. IE:
>
> CREATE FUNCTION ...
>   SELECT old.field FROM old.old;
>
> That will end up as
>
>   SELECT new.field FROM new.old
>
> which won't work.
>
> My objection is not about some corner case: it's the general
>> idea of patching the entire body of a function without a fully-fledged
>> parser that is dead on arrival.
>>
>
> ISTM that's also the biggest blocker for allowing extensions that refer to
> other schemas to be relocatable. It would be interesting if we had some way
> to handle this inside function bodies, perhaps via something equivalent to
> @extschema@.
> --
> Jim Nasby, Data Architect, Blue Treble Consulting, Austin TX
> Experts in Analytics, Data Architecture and PostgreSQL
> Data in Trouble? Get it in Treble! http://BlueTreble.com
>



-- 
*Melvin Davidson*
I reserve the right to fantasize.  Whether or not you
wish to share my fantasy is entirely up to you.


Re: [GENERAL] clone_schema function

2015-09-14 Thread Melvin Davidson
Actually, on further thought, you example shows that it works correctly
because we do want all references to the old schema to be changed to the
new schema, since all copies of functions will now reside in the new
schema. Otherwise, there is no point of duplicating those functions.

On Mon, Sep 14, 2015 at 8:42 PM, Melvin Davidson 
wrote:

> Jim,
>
> Have you actually tried this, or is it just a theory? AFAIK, the function
> will work because only the schema name is changed.. So please provide
> a full working example of a function that fails and I will attempt a
> solution.
>
> On Mon, Sep 14, 2015 at 6:36 PM, Jim Nasby 
> wrote:
>
>> On 9/12/15 9:38 AM, Daniel Verite wrote:
>>
>>> "seriously flawed" is a bit of a stretch. Most sane developers would not
 >have schema names of one letter.
 >They usually name a schema something practical, which totally avoids
 your
 >nit picky exception.

>>> That's confusing the example with the problem it shows.
>>>
>>> Another example could be:
>>> if the source schema is "public" and the function body contains
>>> GRANT SELECT on sometable to public;
>>> then this statement would be wrongly altered by replace().
>>>
>>
>> Well, the new version actually fixes that. But you could still trip this
>> up, certainly in the functions. IE:
>>
>> CREATE FUNCTION ...
>>   SELECT old.field FROM old.old;
>>
>> That will end up as
>>
>>   SELECT new.field FROM new.old
>>
>> which won't work.
>>
>> My objection is not about some corner case: it's the general
>>> idea of patching the entire body of a function without a fully-fledged
>>> parser that is dead on arrival.
>>>
>>
>> ISTM that's also the biggest blocker for allowing extensions that refer
>> to other schemas to be relocatable. It would be interesting if we had some
>> way to handle this inside function bodies, perhaps via something equivalent
>> to @extschema@.
>> --
>> Jim Nasby, Data Architect, Blue Treble Consulting, Austin TX
>> Experts in Analytics, Data Architecture and PostgreSQL
>> Data in Trouble? Get it in Treble! http://BlueTreble.com
>>
>
>
>
> --
> *Melvin Davidson*
> I reserve the right to fantasize.  Whether or not you
> wish to share my fantasy is entirely up to you.
>



-- 
*Melvin Davidson*
I reserve the right to fantasize.  Whether or not you
wish to share my fantasy is entirely up to you.


Re: [GENERAL] clone_schema function

2015-09-12 Thread Daniel Verite
Melvin Davidson wrote:

> "seriously flawed" is a bit of a stretch. Most sane developers would not
> have schema names of one letter. 
> They usually name a schema something practical, which totally avoids your
> nit picky exception.

That's confusing the example with the problem it shows.

Another example could be:
if the source schema is "public" and the function body contains
   GRANT SELECT on sometable to public;
then this statement would be wrongly altered by replace().

My objection is not about some corner case: it's the general
idea of patching the entire body of a function without a fully-fledged
parser that is dead on arrival.


Best regards,
-- 
Daniel Vérité
PostgreSQL-powered mailer: http://www.manitou-mail.org
Twitter: @DanielVerite


-- 
Sent via pgsql-general mailing list (pgsql-general@postgresql.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-general


Re: [GENERAL] clone_schema function

2015-09-12 Thread Melvin Davidson
With thanks to a suggestion by David G. Johnston, I've attached another
revised version
of the function that hopefully eliminates the problem reported by Daniel
Verite.
This version also handles CamelCase schemas and tables better.

If anyone else finds a problem, kindly attach a dump of the schema to
duplicate the problem.


On Sat, Sep 12, 2015 at 10:38 AM, Daniel Verite 
wrote:

> Melvin Davidson wrote:
>
> > "seriously flawed" is a bit of a stretch. Most sane developers would not
> > have schema names of one letter.
> > They usually name a schema something practical, which totally avoids your
> > nit picky exception.
>
> That's confusing the example with the problem it shows.
>
> Another example could be:
> if the source schema is "public" and the function body contains
>GRANT SELECT on sometable to public;
> then this statement would be wrongly altered by replace().
>
> My objection is not about some corner case: it's the general
> idea of patching the entire body of a function without a fully-fledged
> parser that is dead on arrival.
>
>
> Best regards,
> --
> Daniel Vérité
> PostgreSQL-powered mailer: http://www.manitou-mail.org
> Twitter: @DanielVerite
>



-- 
*Melvin Davidson*
I reserve the right to fantasize.  Whether or not you
wish to share my fantasy is entirely up to you.
-- Function: clone_schema(text, text, boolean)

-- DROP FUNCTION clone_schema(text, text, boolean);

CREATE OR REPLACE FUNCTION clone_schema(
source_schema text,
dest_schema text,
include_recs boolean)
  RETURNS void AS
$BODY$

--  This function will clone all sequences, tables, data, views & functions 
from any existing schema to a new one
-- SAMPLE CALL:
-- SELECT clone_schema('public', 'new_schema', TRUE);

DECLARE
  src_oid  oid;
  tbl_oid  oid;
  func_oid oid;
  object   text;
  buffer   text;
  srctbl   text;
  default_ text;
  column_  text;
  qry  text;
  dest_qry text;
  v_deftext;
  seqval   bigint;
  sq_last_valuebigint;
  sq_max_value bigint;
  sq_start_value   bigint;
  sq_increment_by  bigint;
  sq_min_value bigint;
  sq_cache_value   bigint;
  sq_log_cnt   bigint;
  sq_is_called boolean;
  sq_is_cycled boolean;
  sq_cycledchar(10);

BEGIN

-- Check that source_schema exists
  SELECT oid INTO src_oid
FROM pg_namespace
   WHERE nspname = quote_ident(source_schema);
  IF NOT FOUND
THEN 
RAISE NOTICE 'source schema % does not exist!', source_schema;
RETURN ;
  END IF;

  -- Check that dest_schema does not yet exist
  PERFORM nspname 
FROM pg_namespace
   WHERE nspname = quote_ident(dest_schema);
  IF FOUND
THEN 
RAISE NOTICE 'dest schema % already exists!', dest_schema;
RETURN ;
  END IF;

  EXECUTE 'CREATE SCHEMA ' || quote_ident(dest_schema) ;

  -- Create sequences
  -- TODO: Find a way to make this sequence's owner is the correct table.
  FOR object IN
SELECT sequence_name::text 
  FROM information_schema.sequences
 WHERE sequence_schema = quote_ident(source_schema)
  LOOP
EXECUTE 'CREATE SEQUENCE ' || quote_ident(dest_schema) || '.' || 
quote_ident(object);
srctbl := quote_ident(source_schema) || '.' || quote_ident(object);

EXECUTE 'SELECT last_value, max_value, start_value, increment_by, 
min_value, cache_value, log_cnt, is_cycled, is_called 
  FROM ' || quote_ident(source_schema) || '.' || 
quote_ident(object) || ';' 
  INTO sq_last_value, sq_max_value, sq_start_value, 
sq_increment_by, sq_min_value, sq_cache_value, sq_log_cnt, sq_is_cycled, 
sq_is_called ; 

IF sq_is_cycled 
  THEN 
sq_cycled := 'CYCLE';
ELSE
sq_cycled := 'NO CYCLE';
END IF;

EXECUTE 'ALTER SEQUENCE '   || quote_ident(dest_schema) || '.' || 
quote_ident(object) 
|| ' INCREMENT BY ' || sq_increment_by
|| ' MINVALUE ' || sq_min_value 
|| ' MAXVALUE ' || sq_max_value
|| ' START WITH '   || sq_start_value
|| ' RESTART '  || sq_min_value 
|| ' CACHE '|| sq_cache_value 
|| sq_cycled || ' ;' ;

buffer := quote_ident(dest_schema) || '.' || quote_ident(object);
IF include_recs 
THEN
EXECUTE 'SELECT setval( ''' || buffer || ''', ' || sq_last_value || 
', ' || sq_is_called || ');' ; 
ELSE
EXECUTE 'SELECT setval( ''' || buffer || ''', ' || sq_start_value 
|| ', ' || sq_is_called || ');' ;
END IF;

  END LOOP;

-- Create tables 
  FOR object IN
SELECT TABLE_NAME::text 
  FROM information_schema.tables 
 WHERE table_schema = quote_ident(source_schema)
   AND table_type = 'BASE TABLE'

  LOOP
buffer := quote_ident(dest_schema) || '.' || quote_ident(object);
EXECUTE 'CREATE TABLE ' || buffer || ' (LIKE ' || 
quote_ident(source_schema) || '.' || quote_ident(object) 
|| ' 

Re: [GENERAL] clone_schema function

2015-09-11 Thread Melvin Davidson
Alvaro,

no I haven't updated the wiki (or git). To be honest, I'm retired and I
just don't want to bother learning something new,
but I do enjoy helping othersfrom time to time. I would consider it a favor
if you would do the update for me.

TIA,
Melvin

On Fri, Sep 11, 2015 at 12:30 PM, Alvaro Herrera 
wrote:

> Melvin Davidson wrote:
> > Here is one more tweak of clone_schema.
>
> Are you updating the wiki to match?  If not (why?), I think at the very
> least you should add a link in the wiki page to this thread.
>
> --
> Álvaro Herrerahttp://www.2ndQuadrant.com/
> PostgreSQL Development, 24x7 Support, Remote DBA, Training & Services
>



-- 
*Melvin Davidson*
I reserve the right to fantasize.  Whether or not you
wish to share my fantasy is entirely up to you.


Re: [GENERAL] clone_schema function

2015-09-11 Thread Melvin Davidson
Thank you very much Alvaro. Now I can go back to being Chief Engineer of
Sleeping Late @ retired. :)

On Fri, Sep 11, 2015 at 2:21 PM, Alvaro Herrera 
wrote:

> Melvin Davidson wrote:
> > Alvaro,
> >
> > no I haven't updated the wiki (or git). To be honest, I'm retired and I
> > just don't want to bother learning something new,
> > but I do enjoy helping othersfrom time to time. I would consider it a
> favor
> > if you would do the update for me.
>
> I wouldn't want to prevent your enjoyment of learning something new such
> as editing the wiki -- in spite of which I added a link to the wiki.
>
> --
> Álvaro Herrerahttp://www.2ndQuadrant.com/
> PostgreSQL Development, 24x7 Support, Remote DBA, Training & Services
>



-- 
*Melvin Davidson*
I reserve the right to fantasize.  Whether or not you
wish to share my fantasy is entirely up to you.


Re: [GENERAL] clone_schema function

2015-09-11 Thread Alvaro Herrera
Melvin Davidson wrote:
> Here is one more tweak of clone_schema.

Are you updating the wiki to match?  If not (why?), I think at the very
least you should add a link in the wiki page to this thread.

-- 
Álvaro Herrerahttp://www.2ndQuadrant.com/
PostgreSQL Development, 24x7 Support, Remote DBA, Training & Services


-- 
Sent via pgsql-general mailing list (pgsql-general@postgresql.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-general


Re: [GENERAL] clone_schema function

2015-09-11 Thread Alvaro Herrera
Melvin Davidson wrote:
> Alvaro,
> 
> no I haven't updated the wiki (or git). To be honest, I'm retired and I
> just don't want to bother learning something new,
> but I do enjoy helping othersfrom time to time. I would consider it a favor
> if you would do the update for me.

I wouldn't want to prevent your enjoyment of learning something new such
as editing the wiki -- in spite of which I added a link to the wiki.

-- 
Álvaro Herrerahttp://www.2ndQuadrant.com/
PostgreSQL Development, 24x7 Support, Remote DBA, Training & Services


-- 
Sent via pgsql-general mailing list (pgsql-general@postgresql.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-general


Re: [GENERAL] clone_schema function

2015-09-11 Thread Melvin Davidson
"seriously flawed" is a bit of a stretch. Most sane developers would not
have schema names of one letter.
They usually name a schema something practical, which totally avoids your
nit picky exception.
However, if you are that concerned about the "serious flaw", you have the
option of using the method
of dumping the schema, editing the dump and reloading. Or, I invite you to
use your great skills and
write a better method.

On Fri, Sep 11, 2015 at 4:06 PM, Daniel Verite 
wrote:

> Melvin Davidson wrote:
>
> > I've added error checking and verified that it now copies the
> > current sequnce values, table data, views and functions.
>
> The code dealing with functions is seriously flawed.
>
> Consider that part:
>  SELECT pg_get_functiondef(func_oid) INTO qry;
>  SELECT replace(qry, source_schema, dest_schema) INTO dest_qry;
>  EXECUTE dest_qry;
>
> It suggests that to duplicate a function in schema A to B,
> every letter A in the entire function definition should be replaced
> by B, garbling everything along the way.
> For example CREATE FUNCTION would become CREBTE FUNCTION,
> DECLARE would become DECLBRE and so on.
>
> Best regards,
> --
> Daniel Vérité
> PostgreSQL-powered mailer: http://www.manitou-mail.org
> Twitter: @DanielVerite
>



-- 
*Melvin Davidson*
I reserve the right to fantasize.  Whether or not you
wish to share my fantasy is entirely up to you.


Re: [GENERAL] clone_schema function

2015-09-11 Thread Alvaro Herrera
Melvin Davidson wrote:
> Thank you very much Alvaro. Now I can go back to being Chief Engineer of
> Sleeping Late @ retired. :)

What?  No!  You still have a lot of other Snippet pages to go through to
improve ;-)


-- 
Álvaro Herrerahttp://www.2ndQuadrant.com/
PostgreSQL Development, 24x7 Support, Remote DBA, Training & Services


-- 
Sent via pgsql-general mailing list (pgsql-general@postgresql.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-general


Re: [GENERAL] clone_schema function

2015-09-11 Thread Daniel Verite
Melvin Davidson wrote:

> I've added error checking and verified that it now copies the
> current sequnce values, table data, views and functions.

The code dealing with functions is seriously flawed.

Consider that part:
 SELECT pg_get_functiondef(func_oid) INTO qry;
 SELECT replace(qry, source_schema, dest_schema) INTO dest_qry;
 EXECUTE dest_qry;

It suggests that to duplicate a function in schema A to B,
every letter A in the entire function definition should be replaced
by B, garbling everything along the way.
For example CREATE FUNCTION would become CREBTE FUNCTION,
DECLARE would become DECLBRE and so on.

Best regards,
-- 
Daniel Vérité
PostgreSQL-powered mailer: http://www.manitou-mail.org
Twitter: @DanielVerite


-- 
Sent via pgsql-general mailing list (pgsql-general@postgresql.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-general


Re: [GENERAL] clone_schema function

2015-09-11 Thread Melvin Davidson
Igor & David,

You are correct, I am subject to criticism, However, I have spent a few
days getting this to work as it should and it now does.
Even though the chance of a collision is not zero, it is still low and the
function does work.
I don't mind criticism, but when someone finds a problem, the least they
can do is suggest a fix, as you have David.

I'll try that and test over the weekend.. Or I also invite you to submit a
fixed version.

On Fri, Sep 11, 2015 at 4:39 PM, David G. Johnston <
david.g.johns...@gmail.com> wrote:

> On Fri, Sep 11, 2015 at 4:23 PM, Melvin Davidson 
> wrote:
>
>> "seriously flawed" is a bit of a stretch. Most sane developers would not
>> have schema names of one letter.
>> They usually name a schema something practical, which totally avoids your
>> nit picky exception.
>> However, if you are that concerned about the "serious flaw", you have the
>> option of using the method
>> of dumping the schema, editing the dump and reloading. Or, I invite you
>> to use your great skills and
>> write a better method.
>>
>>>
>>>  SELECT replace(qry, source_schema, dest_schema) INTO dest_qry;
>>>
>>
> Or maybe you can at least mitigate the potential problem a bit by changing
> this to read:
>
> replace(qry, source_schema || '.', dest_schema || '.') INTO dest_qry; ...
>
> Posting code for public consumption involves accepting constructive
> criticism and even if the example is contrived I'm doubting the possibility
> of collision is as close to zero as you think it may be or as close as it
> could be with a simple re-evaluation of what constraints as imposed on a
> particular sequence of characters being interpreted as a schema.  You do
> still end up with a possible false-positive when you have a
> (column.composite).composite_field expression.
>
> Regular expressions could maybe help here since the leading character is
> limited too...but less so then the trailing character.
>
> David J.
>
>
>


-- 
*Melvin Davidson*
I reserve the right to fantasize.  Whether or not you
wish to share my fantasy is entirely up to you.


Re: [GENERAL] clone_schema function

2015-09-11 Thread David G. Johnston
On Fri, Sep 11, 2015 at 4:23 PM, Melvin Davidson 
wrote:

> "seriously flawed" is a bit of a stretch. Most sane developers would not
> have schema names of one letter.
> They usually name a schema something practical, which totally avoids your
> nit picky exception.
> However, if you are that concerned about the "serious flaw", you have the
> option of using the method
> of dumping the schema, editing the dump and reloading. Or, I invite you to
> use your great skills and
> write a better method.
>
>>
>>  SELECT replace(qry, source_schema, dest_schema) INTO dest_qry;
>>
>
Or maybe you can at least mitigate the potential problem a bit by changing
this to read:

replace(qry, source_schema || '.', dest_schema || '.') INTO dest_qry; ...

Posting code for public consumption involves accepting constructive
criticism and even if the example is contrived I'm doubting the possibility
of collision is as close to zero as you think it may be or as close as it
could be with a simple re-evaluation of what constraints as imposed on a
particular sequence of characters being interpreted as a schema.  You do
still end up with a possible false-positive when you have a
(column.composite).composite_field expression.

Regular expressions could maybe help here since the leading character is
limited too...but less so then the trailing character.

David J.


Re: [GENERAL] clone_schema function

2015-09-11 Thread Igor Neyman


From: pgsql-general-ow...@postgresql.org 
[mailto:pgsql-general-ow...@postgresql.org] On Behalf Of Melvin Davidson
Sent: Friday, September 11, 2015 4:24 PM
To: Daniel Verite <dan...@manitou-mail.org>
Cc: pgsql-general@postgresql.org
Subject: Re: [GENERAL] clone_schema function

"seriously flawed" is a bit of a stretch. Most sane developers would not have 
schema names of one letter.
They usually name a schema something practical, which totally avoids your nit 
picky exception.
However, if you are that concerned about the "serious flaw", you have the 
option of using the method
of dumping the schema, editing the dump and reloading. Or, I invite you to use 
your great skills and
write a better method.

On Fri, Sep 11, 2015 at 4:06 PM, Daniel Verite 
<dan...@manitou-mail.org<mailto:dan...@manitou-mail.org>> wrote:
Melvin Davidson wrote:

> I've added error checking and verified that it now copies the
> current sequnce values, table data, views and functions.

The code dealing with functions is seriously flawed.

Consider that part:
 SELECT pg_get_functiondef(func_oid) INTO qry;
 SELECT replace(qry, source_schema, dest_schema) INTO dest_qry;
 EXECUTE dest_qry;

It suggests that to duplicate a function in schema A to B,
every letter A in the entire function definition should be replaced
by B, garbling everything along the way.
For example CREATE FUNCTION would become CREBTE FUNCTION,
DECLARE would become DECLBRE and so on.

Best regards,
--
Daniel Vérité
PostgreSQL-powered mailer: http://www.manitou-mail.org
Twitter: @DanielVerite



It does not have to be one-letter schema name.
Consider the following:

Schema called “vector” has a table called “vector_config” referenced in some 
function.
Now, what happens if schema “vector” is copied into some destination schema 
using your script?

Melvin, you needn’t consider every critique of your script to be a personal 
attack on you.

Regards,
Igor Neyman




Re: [GENERAL] clone_schema function

2015-09-11 Thread Melvin Davidson
Here is one more tweak of clone_schema.

I've added an include_recs flag.
If FALSE, then no records are copied into the tables from the old_schema
and all sequences start with the minimum value.
If TRUE, then all records are copied and sequences are set tot the last
value.


On Thu, Sep 10, 2015 at 11:52 AM, Melvin Davidson <melvin6...@gmail.com>
wrote:

> Yes, however, the documentation would be a lot clearer if it said "copies
> all constraints except foreign keys". I've made this known.
>
> At any rate, I've attached a new version of the function that now does
> copy the foreign keys. Let me know if I missed anything else.
>
> On Thu, Sep 10, 2015 at 9:09 AM, Igor Neyman <iney...@perceptron.com>
> wrote:
>
>>
>>
>>
>>
>> *From:* Melvin Davidson [mailto:melvin6...@gmail.com]
>> *Sent:* Wednesday, September 09, 2015 4:48 PM
>> *To:* Igor Neyman <iney...@perceptron.com>
>> *Cc:* pgsql-general@postgresql.org
>> *Subject:* Re: [GENERAL] clone_schema function
>>
>>
>>
>> Thanks Igor,
>>
>> hmm, apparently the "INCLUDING CONSTRAINTS' option of "CREATE TABLE' has
>> a glitch and only includes the primary key.
>>
>> I also noticed that INCLUDING ALL generates an error, so I'll have to
>> report that also.
>>
>> I'll go eat some crow and work on a fix to add all constraints in the
>> meantime.
>>
>>
>>
>>
>>
>> It’s not a bug.
>>
>> According to docs:
>>
>> “Not-null constraints are always copied to the new table. CHECK
>> constraints will only be copied if INCLUDING CONSTRAINTS is specified;
>> other types of constraints will never be copied.”
>>
>> So, FK constraints are not supposed to be copied.
>>
>>
>>
>> Regards,
>>
>> Igor Neyman
>>
>
>
>
> --
> *Melvin Davidson*
> I reserve the right to fantasize.  Whether or not you
> wish to share my fantasy is entirely up to you.
>



-- 
*Melvin Davidson*
I reserve the right to fantasize.  Whether or not you
wish to share my fantasy is entirely up to you.


clone_schema.sql
Description: Binary data

-- 
Sent via pgsql-general mailing list (pgsql-general@postgresql.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-general


Re: [GENERAL] clone_schema function

2015-09-10 Thread Igor Neyman


From: Melvin Davidson [mailto:melvin6...@gmail.com]
Sent: Wednesday, September 09, 2015 4:48 PM
To: Igor Neyman <iney...@perceptron.com>
Cc: pgsql-general@postgresql.org
Subject: Re: [GENERAL] clone_schema function

Thanks Igor,
hmm, apparently the "INCLUDING CONSTRAINTS' option of "CREATE TABLE' has a 
glitch and only includes the primary key.
I also noticed that INCLUDING ALL generates an error, so I'll have to report 
that also.
I'll go eat some crow and work on a fix to add all constraints in the meantime.


It’s not a bug.
According to docs:
“Not-null constraints are always copied to the new table. CHECK constraints 
will only be copied if INCLUDING CONSTRAINTS is specified; other types of 
constraints will never be copied.”
So, FK constraints are not supposed to be copied.

Regards,
Igor Neyman


Re: [GENERAL] clone_schema function

2015-09-10 Thread Melvin Davidson
Yes, however, the documentation would be a lot clearer if it said "copies
all constraints except foreign keys". I've made this known.

At any rate, I've attached a new version of the function that now does copy
the foreign keys. Let me know if I missed anything else.

On Thu, Sep 10, 2015 at 9:09 AM, Igor Neyman <iney...@perceptron.com> wrote:

>
>
>
>
> *From:* Melvin Davidson [mailto:melvin6...@gmail.com]
> *Sent:* Wednesday, September 09, 2015 4:48 PM
> *To:* Igor Neyman <iney...@perceptron.com>
> *Cc:* pgsql-general@postgresql.org
> *Subject:* Re: [GENERAL] clone_schema function
>
>
>
> Thanks Igor,
>
> hmm, apparently the "INCLUDING CONSTRAINTS' option of "CREATE TABLE' has a
> glitch and only includes the primary key.
>
> I also noticed that INCLUDING ALL generates an error, so I'll have to
> report that also.
>
> I'll go eat some crow and work on a fix to add all constraints in the
> meantime.
>
>
>
>
>
> It’s not a bug.
>
> According to docs:
>
> “Not-null constraints are always copied to the new table. CHECK
> constraints will only be copied if INCLUDING CONSTRAINTS is specified;
> other types of constraints will never be copied.”
>
> So, FK constraints are not supposed to be copied.
>
>
>
> Regards,
>
> Igor Neyman
>



-- 
*Melvin Davidson*
I reserve the right to fantasize.  Whether or not you
wish to share my fantasy is entirely up to you.
-- Function: clone_schema(text, text)

-- DROP FUNCTION clone_schema(text, text);

CREATE OR REPLACE FUNCTION clone_schema(
source_schema text,
dest_schema text)
  RETURNS void AS
$BODY$

--  This function will clone all sequences, tables, data, views & functions 
from any existing schema to a new one
-- SAMPLE CALL:
-- SELECT clone_schema('public', 'new_schema');

DECLARE
  src_oid  oid;
  tbl_oid  oid;
  func_oid oid;
  object   text;
  buffer   text;
  srctbl   text;
  default_ text;
  column_  text;
  qry  text;
  dest_qry text;
  v_deftext;
  seqval   bigint;
  sq_last_valuebigint;
  sq_max_value bigint;
  sq_start_value   bigint;
  sq_increment_by  bigint;
  sq_min_value bigint;
  sq_cache_value   bigint;
  sq_log_cnt   bigint;
  sq_is_called boolean;
  sq_is_cycled boolean;
  sq_cycledchar(10);

BEGIN

-- Check that source_schema exists
  SELECT oid INTO src_oid
FROM pg_namespace
   WHERE nspname = quote_ident(source_schema);
  IF NOT FOUND
THEN 
RAISE NOTICE 'source schema % does not exist!', source_schema;
RETURN ;
  END IF;

  -- Check that dest_schema does not yet exist
  PERFORM nspname 
FROM pg_namespace
   WHERE nspname = quote_ident(dest_schema);
  IF FOUND
THEN 
RAISE NOTICE 'dest schema % already exists!', dest_schema;
RETURN ;
  END IF;

  EXECUTE 'CREATE SCHEMA ' || quote_ident(dest_schema) ;

  -- Create sequences
  -- TODO: Find a way to make this sequence's owner is the correct table.
  FOR object IN
SELECT sequence_name::text 
  FROM information_schema.sequences
 WHERE sequence_schema = quote_ident(source_schema)
  LOOP
EXECUTE 'CREATE SEQUENCE ' || quote_ident(dest_schema) || '.' || 
quote_ident(object);
srctbl := quote_ident(source_schema) || '.' || quote_ident(object);

EXECUTE 'SELECT last_value, max_value, start_value, increment_by, 
min_value, cache_value, log_cnt, is_cycled, is_called 
  FROM ' || quote_ident(source_schema) || '.' || 
quote_ident(object) || ';' 
  INTO sq_last_value, sq_max_value, sq_start_value, 
sq_increment_by, sq_min_value, sq_cache_value, sq_log_cnt, sq_is_cycled, 
sq_is_called ; 

IF sq_is_cycled 
  THEN 
sq_cycled := 'CYCLE';
ELSE
sq_cycled := 'NO CYCLE';
END IF;

EXECUTE 'ALTER SEQUENCE '   || quote_ident(dest_schema) || '.' || 
quote_ident(object) 
|| ' INCREMENT BY ' || sq_increment_by
|| ' MINVALUE ' || sq_min_value 
|| ' MAXVALUE ' || sq_max_value
|| ' START WITH '   || sq_start_value
|| ' RESTART '  || sq_min_value 
|| ' CACHE '|| sq_cache_value 
|| sq_cycled || ' ;' ;

buffer := quote_ident(dest_schema) || '.' || quote_ident(object);
EXECUTE 'SELECT setval( ''' || buffer || ''', ' || sq_last_value || ', ' || 
sq_is_called || ');' ;

  END LOOP;

-- Create tables 
  FOR object IN
SELECT TABLE_NAME::text 
  FROM information_schema.tables 
 WHERE table_schema = quote_ident(source_schema)
   AND table_type = 'BASE TABLE'

  LOOP
buffer := dest_schema || '.' || quote_ident(object);
EXECUTE 'CREATE TABLE ' || buffer || ' (LIKE ' || 
quote_ident(source_schema) || '.' || quote_ident(object) 
|| ' INCLUDING ALL)';

-- Insert records from so

[GENERAL] clone_schema function

2015-09-09 Thread Melvin Davidson
I noted there was an inquiry as to how to copy or clone_schema
an entire schema. The standard method for doing that is to
1. pg_dump the schema in plain format
2. edit the dump file and change all occurrences of the schema name
3. reload the dump into the new schema.

The attached function is an alternate method for doing that.
It is a revision of the clone_schema by by Emanuel '3manuek'
from https://wiki.postgresql.org/wiki/Clone_schema

Originally, it did not copy views, functions or data from
the source schema despite the claim that it "copies everything".

I've added error checking and verified that it now copies the
current sequnce values, table data, views and functions.

As always, use with caution.
-- 
*Melvin Davidson*
I reserve the right to fantasize.  Whether or not you
wish to share my fantasy is entirely up to you.
-- Function: clone_schema(text, text)

-- DROP FUNCTION clone_schema(text, text);

CREATE OR REPLACE FUNCTION clone_schema(
source_schema text,
dest_schema text)
  RETURNS void AS
$BODY$
-- by Emanuel '3manuek' 
-- Revised by Melvin Davidson
--  This function will clone all sequences, tables, data, views & functions 
from any existing schema to a new one
-- SAMPLE CALL:
-- SELECT clone_schema('public', 'new_schema');

DECLARE
  src_oid  oid;
  func_oid oid;
  object   text;
  buffer   text;
  srctbl   text;
  default_ text;
  column_  text;
  qry  text;
  dest_qry text;
  v_deftext;
  seqval   bigint;
  sq_last_valuebigint;
  sq_max_value bigint;
  sq_start_value   bigint;
  sq_increment_by  bigint;
  sq_min_value bigint;
  sq_cache_value   bigint;
  sq_log_cnt   bigint;
  sq_is_called boolean;
  sq_is_cycled boolean;
  sq_cycledchar(10);

BEGIN

-- Check that source_schema exists
  SELECT oid INTO src_oid
FROM pg_namespace
   WHERE nspname = quote_ident(source_schema);
  IF NOT FOUND
THEN 
RAISE NOTICE 'source schema % does not exist!', source_schema;
RETURN ;
  END IF;

  -- Check that dest_schema does not yet exist
  PERFORM nspname 
FROM pg_namespace
   WHERE nspname = quote_ident(dest_schema);
  IF FOUND
THEN 
RAISE NOTICE 'dest schema % already exists!', dest_schema;
RETURN ;
  END IF;

  EXECUTE 'CREATE SCHEMA ' || quote_ident(dest_schema) ;

  -- Create sequences
  -- TODO: Find a way to make this sequence's owner is the correct table.
  FOR object IN
SELECT sequence_name::text 
  FROM information_schema.sequences
 WHERE sequence_schema = quote_ident(source_schema)
  LOOP
EXECUTE 'CREATE SEQUENCE ' || quote_ident(dest_schema) || '.' || 
quote_ident(object);
srctbl := quote_ident(source_schema) || '.' || quote_ident(object);

EXECUTE 'SELECT last_value, max_value, start_value, increment_by, 
min_value, cache_value, log_cnt, is_cycled, is_called 
  FROM ' || quote_ident(source_schema) || '.' || 
quote_ident(object) || ';' 
  INTO sq_last_value, sq_max_value, sq_start_value, 
sq_increment_by, sq_min_value, sq_cache_value, sq_log_cnt, sq_is_cycled, 
sq_is_called ; 

IF sq_is_cycled 
  THEN 
sq_cycled := 'CYCLE';
ELSE
sq_cycled := 'NO CYCLE';
END IF;

EXECUTE 'ALTER SEQUENCE '   || quote_ident(dest_schema) || '.' || 
quote_ident(object) 
|| ' INCREMENT BY ' || sq_increment_by
|| ' MINVALUE ' || sq_min_value 
|| ' MAXVALUE ' || sq_max_value
|| ' START WITH '   || sq_start_value
|| ' RESTART '  || sq_min_value 
|| ' CACHE '|| sq_cache_value 
|| sq_cycled || ' ;' ;

buffer := quote_ident(dest_schema) || '.' || quote_ident(object);
EXECUTE 'SELECT setval( ''' || buffer || ''', ' || sq_last_value || ', ' || 
sq_is_called || ');' ;

  END LOOP;

-- Create tables 
  FOR object IN
SELECT TABLE_NAME::text 
  FROM information_schema.tables 
 WHERE table_schema = quote_ident(source_schema)
   AND table_type = 'BASE TABLE'

  LOOP
buffer := dest_schema || '.' || quote_ident(object);
EXECUTE 'CREATE TABLE ' || buffer || ' (LIKE ' || 
quote_ident(source_schema) || '.' || quote_ident(object) || ' INCLUDING 
CONSTRAINTS INCLUDING INDEXES INCLUDING DEFAULTS)';

-- Insert records from source table
EXECUTE 'INSERT INTO ' || buffer || ' SELECT * FROM ' || 
quote_ident(source_schema) || '.' || quote_ident(object) || ';';
 
FOR column_, default_ IN
  SELECT column_name::text, 
 REPLACE(column_default::text, source_schema, dest_schema) 
FROM information_schema.COLUMNS 
   WHERE table_schema = dest_schema 
 AND TABLE_NAME = object 
 AND column_default LIKE 'nextval(%' || quote_ident(source_schema) || 
'%::regclass)'
LOOP
  EXECUTE 'ALTER TABLE ' || buffer || ' ALTER COLUMN ' || column_ || ' SET 
DEFAULT ' || default_;
END LOOP;
  
  END LOOP;

-- 

Re: [GENERAL] clone_schema function

2015-09-09 Thread Melvin Davidson
Thanks Igor,

hmm, apparently the "INCLUDING CONSTRAINTS' option of "CREATE TABLE' has a
glitch and only includes the primary key.
I also noticed that INCLUDING ALL generates an error, so I'll have to
report that also.

I'll go eat some crow and work on a fix to add all constraints in the
meantime.

On Wed, Sep 9, 2015 at 3:43 PM, Igor Neyman <iney...@perceptron.com> wrote:

>
>
>
>
> *From:* pgsql-general-ow...@postgresql.org [mailto:
> pgsql-general-ow...@postgresql.org] *On Behalf Of *Melvin Davidson
> *Sent:* Wednesday, September 09, 2015 12:31 PM
> *To:* pgsql-general@postgresql.org
> *Subject:* [GENERAL] clone_schema function
>
>
>
>
> I noted there was an inquiry as to how to copy or clone_schema
> an entire schema. The standard method for doing that is to
> 1. pg_dump the schema in plain format
> 2. edit the dump file and change all occurrences of the schema name
> 3. reload the dump into the new schema.
>
> The attached function is an alternate method for doing that.
> It is a revision of the clone_schema by by Emanuel '3manuek'
> from https://wiki.postgresql.org/wiki/Clone_schema
>
> Originally, it did not copy views, functions or data from
> the source schema despite the claim that it "copies everything".
>
> I've added error checking and verified that it now copies the
> current sequnce values, table data, views and functions.
>
> As always, use with caution.
> --
>
> *Melvin Davidson*
>
>
>
> I assume you are aware that this script does not produce complete copy of
> the source schema.
>
> Foregn Key constraints are not recreated along with the tables.
>
>
>
> Regards,
>
> Igor Neyman
>
>
>
>
>



-- 
*Melvin Davidson*
I reserve the right to fantasize.  Whether or not you
wish to share my fantasy is entirely up to you.


Re: [GENERAL] clone_schema function

2015-09-09 Thread Igor Neyman


From: pgsql-general-ow...@postgresql.org 
[mailto:pgsql-general-ow...@postgresql.org] On Behalf Of Melvin Davidson
Sent: Wednesday, September 09, 2015 12:31 PM
To: pgsql-general@postgresql.org
Subject: [GENERAL] clone_schema function


I noted there was an inquiry as to how to copy or clone_schema
an entire schema. The standard method for doing that is to
1. pg_dump the schema in plain format
2. edit the dump file and change all occurrences of the schema name
3. reload the dump into the new schema.

The attached function is an alternate method for doing that.
It is a revision of the clone_schema by by Emanuel '3manuek'
from https://wiki.postgresql.org/wiki/Clone_schema

Originally, it did not copy views, functions or data from
the source schema despite the claim that it "copies everything".

I've added error checking and verified that it now copies the
current sequnce values, table data, views and functions.

As always, use with caution.
--
Melvin Davidson


I assume you are aware that this script does not produce complete copy of the 
source schema.
Foregn Key constraints are not recreated along with the tables.

Regards,
Igor Neyman