Обсуждение: Greetings folks, dumb question maybe?
Hello, I'm a little new at this so please bear with me.
I am trying to create a function that loads 100M test records into a
database, however I am having a hard time building the function that
does so.
I'm trying to do this in PGAdmin III for Ubuntu. Is there something
that I have wrong with this? I know that this works in MySQL (and yes I
know that MySQL bends the SQL Standards), but I am not sure what I am
doing wrong exactly. I am coming up with the error that says there's an
error in my syntax near the v INTEGER := 0 line. I get the same error
in psql as I do in the PGAdmin III.
I have the following so far:
DECLARE
v INTEGER := 0;
BEGIN
while v < 100000000
DO
INSERT INTO unpart_tbl_test VALUES
(v, 'test string data', adddate('1995-01-01', (rand(v)*36520) mod 3652));
v := v + 1;
END WHILE;
END;
Any insight would be greatly appreciated.
- J
On 05/12/2010 01:32 PM, Josh wrote:
> Hello, I'm a little new at this so please bear with me.
>
> I am trying to create a function that loads 100M test records into a
> database, however I am having a hard time building the function that
> does so.
>
> I'm trying to do this in PGAdmin III for Ubuntu. Is there something
> that I have wrong with this? I know that this works in MySQL (and yes
> I know that MySQL bends the SQL Standards), but I am not sure what I
> am doing wrong exactly. I am coming up with the error that says
> there's an error in my syntax near the v INTEGER := 0 line. I get the
> same error in psql as I do in the PGAdmin III.
>
> I have the following so far:
>
> DECLARE
> v INTEGER := 0;
> BEGIN
> while v < 100000000
> DO
> INSERT INTO unpart_tbl_test VALUES
> (v, 'test string data', adddate('1995-01-01', (rand(v)*36520) mod 3652));
> v := v + 1;
> END WHILE;
> END;
>
> Any insight would be greatly appreciated.
>
> - J
after some digging I had to first create a language plpgsql, then I
changed the function to be as follows:
CREATE FUNCTION no_part_tbl() RETURNS void AS '
DECLARE
v INTEGER := 0;
BEGIN
WHILE v < 100000000 LOOP
INSERT INTO no_part_tbl VALUES
(v, "testing no parts", adddate("1995-01-01",
(rand(v)*36520 % 3652));
v := v + 1;
END LOOP;
END;
' LANGUAGE 'plpgsql';
And it seems to accepted the function finally. SOrry for the waste of
bandwidth and anyones time. I'm not used to this syntax, so it will
take me a bit to get on boad with it.
- J
On Wed, May 12, 2010 at 10:32 AM, Josh <jgooding@ttitech.net> wrote: > I am trying to create a function that loads 100M test records into a > database, however I am having a hard time building the function that does > so. Here is one idea a function, but is could be wrapped by one: p2082849b=> INSERT INTO Testtable ( n, c, d ) p2082849b-> WITH RECURSIVE T(n,c,d) as ( SELECT 1, 'A', CAST( '2009-12-31' AS DATE ) + INTERVAL '1 DAY' p2082849b(> UNION ALL SELECT n + 1, c, d + INTERVAL '1 day' p2082849b(> FROM T p2082849b(> WHERE n <= 10000) p2082849b-> SELECT n,c,d FROM T; INSERT 0 10001 -- Regards, Richard Broersma Jr. Visit the Los Angeles PostgreSQL Users Group (LAPUG) http://pugs.postgresql.org/lapug
I've been using the generate_series function and finding it very useful. It generates an integer, but I cast to 'day' interval. Might be useful. doug -----Original Message----- From: pgsql-sql-owner@postgresql.org [mailto:pgsql-sql-owner@postgresql.org] On Behalf Of Richard Broersma Sent: Wednesday, May 12, 2010 4:05 PM To: Josh Cc: pgsql-sql@postgresql.org Subject: Re: [SQL] Greetings folks, dumb question maybe? On Wed, May 12, 2010 at 10:32 AM, Josh <jgooding@ttitech.net> wrote: > I am trying to create a function that loads 100M test records into a > database, however I am having a hard time building the function that does > so. Here is one idea a function, but is could be wrapped by one: p2082849b=> INSERT INTO Testtable ( n, c, d ) p2082849b-> WITH RECURSIVE T(n,c,d) as ( SELECT 1, 'A', CAST( '2009-12-31' AS DATE ) + INTERVAL '1 DAY' p2082849b(> UNION ALL SELECT n + 1, c, d + INTERVAL '1 day' p2082849b(> FROM T p2082849b(> WHERE n <= 10000) p2082849b-> SELECT n,c,d FROM T; INSERT 0 10001 -- Regards, Richard Broersma Jr. Visit the Los Angeles PostgreSQL Users Group (LAPUG) http://pugs.postgresql.org/lapug -- Sent via pgsql-sql mailing list (pgsql-sql@postgresql.org) To make changes to your subscription: http://www.postgresql.org/mailpref/pgsql-sql
On 2010-05-12, Josh <jgooding@ttitech.net> wrote:
> Hello, I'm a little new at this so please bear with me.
>
> I am trying to create a function that loads 100M test records into a
> database, however I am having a hard time building the function that
> does so.
>
> I'm trying to do this in PGAdmin III for Ubuntu. Is there something
> that I have wrong with this? I know that this works in MySQL (and yes I
> know that MySQL bends the SQL Standards), but I am not sure what I am
> doing wrong exactly. I am coming up with the error that says there's an
> error in my syntax near the v INTEGER := 0 line. I get the same error
> in psql as I do in the PGAdmin III.
>
> I have the following so far:
>
> DECLARE
> v INTEGER := 0;
> BEGIN
> while v < 100000000
> DO
> INSERT INTO unpart_tbl_test VALUES
> (v, 'test string data', adddate('1995-01-01', (rand(v)*36520) mod 3652));
> v := v + 1;
> END WHILE;
> END;
>
> Any insight would be greatly appreciated.
>
> - J
don't need a function for that one.
INSERT INTO unpart_tbl_test SELECT GENERATE_SERIES(0,9999999), 'teststring data', date '1995-01-01'
+(floor(random()*36520)::int% 3652);
On Thu, May 13, 2010 at 10:09:51AM +0000, Jasen Betts wrote: > On 2010-05-12, Josh <jgooding@ttitech.net> wrote: > don't need a function for that one. > > INSERT INTO unpart_tbl_test > SELECT GENERATE_SERIES(0,9999999), > 'teststring data', > date '1995-01-01' +(floor(random()*36520)::int % 3652); ...and if you'd rather it were a function anyway, do this: CREATE FUNCTION populate_table() RETURNS VOID AS $$ INSERT INTO unpart_tbl_test SELECT GENERATE_SERIES(0,9999999), 'teststring data', date '1995-01-01' +(floor(random()*36520)::int % 3652); $$ LANGUAGE SQL; -- Joshua Tolley / eggyknap End Point Corporation http://www.endpoint.com