Thread: Re: [COMMITTERS] pgsql-server: Clean up generation of default names

Re: [COMMITTERS] pgsql-server: Clean up generation of default names

From
Christopher Kings-Lynne
Date:
(moved to -hackers)

> If you use sufficiently long table/field names then different tables
> could truncate to the same generated names, and in that case there's
> some risk of concurrently choosing the same "unique" name.  But I don't
> recall anyone having complained of that since we started using this
> technique for choosing index names, so I'm not very worried.  Basically
> what this commit did was propagate the index naming technique to
> constraints and sequences.

Is it conceivable that different SERIAL sequence names could now be 
generated?

ie.  If I upgrade from 7.4 with a dump that looks like this:

CREATE TABLE blah (id SERIAL
);

COPY ...

SELECT SETVAL('blah_id_seq', 10);

Then if the name given to the id sequence is now different, these dumps 
will not restore.  (In this case it will be the same, I'm just 
illustrating the general problem of hard-coding those sequence names in 
the dump - I've never liked it :) )

Chris



Re: [COMMITTERS] pgsql-server: Clean up generation of default names

From
Tom Lane
Date:
Christopher Kings-Lynne <chriskl@familyhealth.com.au> writes:
> Then if the name given to the id sequence is now different, these dumps 
> will not restore.  (In this case it will be the same, I'm just 
> illustrating the general problem of hard-coding those sequence names in 
> the dump - I've never liked it :) )

Yeah, I know ... we ought to find some way around that, but I dunno
what yet ...
        regards, tom lane


Re: [COMMITTERS] pgsql-server: Clean up generation of default names

From
Christopher Kings-Lynne
Date:
> Yeah, I know ... we ought to find some way around that, but I dunno
> what yet ...

My idea, which I tried hacking, but gave up was to do the following:

1. Extend this command:

ALTER SEQUENCE seqname RESTART WITH 17;

to allow:

ALTER SEQUENCE ON table(col) RESTART WITH 17...
or
ALTER SEQUENCE ON table.col RESTART WITH 17...

2. Overload nextval, curval and setval:

SELECT SETVAL('"schema.table"', 'col', 17, false);

3. Or even create a pg_get_sequence() function:

SELECT SETVAL(pg_get_sequence(schema.table, col), 17);

etc.

Chris






Re: [COMMITTERS] pgsql-server: Clean up generation of default

From
Christopher Kings-Lynne
Date:
> 3. Or even create a pg_get_sequence() function:
> 
> SELECT SETVAL(pg_get_sequence(schema.table, col), 17);

Actually, this is the best solution :)

Chris



Re: [COMMITTERS] pgsql-server: Clean up generation of default

From
Michael Glaesemann
Date:
On Jun 11, 2004, at 1:02 PM, Christopher Kings-Lynne wrote:

>> 3. Or even create a pg_get_sequence() function:
>> SELECT SETVAL(pg_get_sequence(schema.table, col), 17);
>
> Actually, this is the best solution :)

John Hansen and I worked this up. It works, though it's not 
schema-aware, afaict.

create or replace function last_val(    text     -- tablename    , text   -- colname    ) returns bigint    language
'sql'as '    select currval(        (select            split_part(adsrc,\'\'\'\',2) as seq        from pg_class
joinpg_attribute on (pg_class.oid = pg_attribute.attrelid)        join pg_attrdef            on (pg_attrdef.adnum =
pg_attribute.attnum           and pg_attrdef.adrelid = pg_attribute.attrelid)        where pg_class.relname = $1
   and pg_attribute.attname = $2)    );    ';
 

Might be a starting point.

Michael Glaesemann
grzm myrealbox com



Re: [COMMITTERS] pgsql-server: Clean up generation of default

From
Christopher Kings-Lynne
Date:
>>> 3. Or even create a pg_get_sequence() function:
>>> SELECT SETVAL(pg_get_sequence(schema.table, col), 17);
>>
>>
>> Actually, this is the best solution :)

OK, attached is a pg_get_serial_sequence(schema, table, column) function
.  I have tested it with crazy names and it seems to be good.  It works
like this:

SELECT setval(pg_get_serial_sequence('public', 'mytable', 'mycol'), 1,
false);

If someone approves it, i'll work on making it a built-in backend
function, and make pg_dump use it.

This will also be great for our app, since we would no longer have to
have hard-coded sequence names in our code.  (For getting last sequence
val on oid-less tables)

Chris



CREATE FUNCTION pg_get_serial_sequence(name, name, name) RETURNS text
    AS '
    SELECT
        pg_catalog.quote_ident(pn_seq.nspname) || ''.'' || pg_catalog.quote_ident(seq.relname)
    FROM
        pg_catalog.pg_namespace pn,
        pg_catalog.pg_class pc,
        pg_catalog.pg_attribute pa,
        pg_catalog.pg_depend pd,
        pg_catalog.pg_class seq,
        pg_catalog.pg_namespace pn_seq
    WHERE
        pn.nspname=$1
        AND pc.relname=$2
        AND pa.attname=$3
        AND pn.oid=pc.relnamespace
        AND pc.oid=pa.attrelid
        AND pd.objid=seq.oid
        AND pd.classid=seq.tableoid
        AND pd.refclassid=seq.tableoid
        AND pd.refobjid=pc.oid
        AND pd.refobjsubid=pa.attnum
        AND pd.deptype=''i''
        AND seq.relkind=''S''
        AND seq.relnamespace=pn_seq.oid
'
    LANGUAGE sql;


Re: [COMMITTERS] pgsql-server: Clean up generation of default

From
Darcy Buskermolen
Date:
On June 11, 2004 05:51 am, Christopher Kings-Lynne wrote:
> >>> 3. Or even create a pg_get_sequence() function:
> >>> SELECT SETVAL(pg_get_sequence(schema.table, col), 17);
> >>
> >> Actually, this is the best solution :)
>
> OK, attached is a pg_get_serial_sequence(schema, table, column) function
> .  I have tested it with crazy names and it seems to be good.  It works
> like this:
>
> SELECT setval(pg_get_serial_sequence('public', 'mytable', 'mycol'), 1,
> false);

I'd be inclined to make it only take 2 args, table, col  where table can be 
namespace qualified.  This allows people who arn't namespace aware to just do 
SELECT pg_get_serial_sequence('mytable','mycol') and have it return the 
correct item following searchpath..  I would think this would then become 
consistant with the standard behavior.  Not to mention it would also allow 
for easier moving schema form one namespace to another.. 



>
> If someone approves it, i'll work on making it a built-in backend
> function, and make pg_dump use it.
>
> This will also be great for our app, since we would no longer have to
> have hard-coded sequence names in our code.  (For getting last sequence
> val on oid-less tables)
>
> Chris

-- 
Darcy Buskermolen
Wavefire Technologies Corp.
ph: 250.717.0200
fx:  250.763.1759
http://www.wavefire.com


Re: [COMMITTERS] pgsql-server: Clean up generation of default

From
Christopher Kings-Lynne
Date:
> I'd be inclined to make it only take 2 args, table, col  where table can be
> namespace qualified.  This allows people who arn't namespace aware to just do
> SELECT pg_get_serial_sequence('mytable','mycol') and have it return the
> correct item following searchpath..  I would think this would then become
> consistant with the standard behavior.  Not to mention it would also allow
> for easier moving schema form one namespace to another..

OK, attached is a file with the original function, and an overloaded one
that just takes table and column.  It searches your current search_path
to find the first matching table.

Tom, do you have any opinion on whether the former or latter function
would be a good solution to the pg_dump issue?

Chris

CREATE FUNCTION pg_get_serial_sequence(name, name, name) RETURNS text
    AS '
    SELECT
        pg_catalog.quote_ident(pn_seq.nspname) || ''.'' || pg_catalog.quote_ident(seq.relname)
    FROM
        pg_catalog.pg_namespace pn,
        pg_catalog.pg_class pc,
        pg_catalog.pg_attribute pa,
        pg_catalog.pg_depend pd,
        pg_catalog.pg_class seq,
        pg_catalog.pg_namespace pn_seq
    WHERE
        pn.nspname=$1
        AND pc.relname=$2
        AND pa.attname=$3
        AND pn.oid=pc.relnamespace
        AND pc.oid=pa.attrelid
        AND pd.objid=seq.oid
        AND pd.classid=seq.tableoid
        AND pd.refclassid=seq.tableoid
        AND pd.refobjid=pc.oid
        AND pd.refobjsubid=pa.attnum
        AND pd.deptype=''i''
        AND seq.relkind=''S''
        AND seq.relnamespace=pn_seq.oid
'
    LANGUAGE sql;

CREATE FUNCTION pg_get_serial_sequence(name, name) RETURNS text
    AS '
    SELECT
        pg_catalog.quote_ident(pn_seq.nspname) || ''.'' || pg_catalog.quote_ident(seq.relname)
    FROM
        pg_catalog.pg_class pc,
        pg_catalog.pg_attribute pa,
        pg_catalog.pg_depend pd,
        pg_catalog.pg_class seq,
        pg_catalog.pg_namespace pn_seq
    WHERE
        pg_catalog.pg_table_is_visible(pc.oid)
        AND pc.relname=$1
        AND pa.attname=$2
        AND pc.oid=pa.attrelid
        AND pd.objid=seq.oid
        AND pd.classid=seq.tableoid
        AND pd.refclassid=seq.tableoid
        AND pd.refobjid=pc.oid
        AND pd.refobjsubid=pa.attnum
        AND pd.deptype=''i''
        AND seq.relkind=''S''
        AND seq.relnamespace=pn_seq.oid
'
    LANGUAGE sql;


Re: [COMMITTERS] pgsql-server: Clean up generation of default

From
Tom Lane
Date:
Christopher Kings-Lynne <chriskl@familyhealth.com.au> writes:
> OK, attached is a file with the original function, and an overloaded one 
> that just takes table and column.  It searches your current search_path 
> to find the first matching table.

The right way to do this at the C level would be to use the same
infrastructure as nextval() does to accept arguments like 'foo' and
'"Foo"."Bar"'.  There's no reason to restrict the two-argument form
to the current search_path.

Given that you do that, I'm not sure that a three-argument form is even
needed.  AFAIR no one has asked for a two-argument form of nextval...
        regards, tom lane


Re: [COMMITTERS] pgsql-server: Clean up generation of

From
Christopher Kings-Lynne
Date:
> The right way to do this at the C level would be to use the same
> infrastructure as nextval() does to accept arguments like 'foo' and
> '"Foo"."Bar"'.  There's no reason to restrict the two-argument form
> to the current search_path.

Is it possible to do that in SQL?  eg. is there anything you can do to go:

select '"Foo"."Bar"'::regclassoid;

Or something?

I'm trying to avoid doing it in C as it seems like it would be a pita.

Chris




Re: [COMMITTERS] pgsql-server: Clean up generation of

From
Tom Lane
Date:
Christopher Kings-Lynne <chriskl@familyhealth.com.au> writes:
> I'm trying to avoid doing it in C as it seems like it would be a pita.

I think it would be simpler in C than this mess in SQL is ;-).  You
would not of course implement it in any way that would look like the
SQL query ... but there are existing utility subroutines for most of
the bits that are being done with joins here.
        regards, tom lane