Обсуждение: Multi-row update w. plpgsql function

Поиск
Список
Период
Сортировка

Multi-row update w. plpgsql function

От
Daniel Hertz
Дата:
Given a set of checkbox values that are submitted through an html form, 
how do you loop through the submitted values to update more than one row 
in a table?

Imagine a table called 'message_table':

mid | message | status
----+---------+------- 1  |  Text1   |  H 2  |  Text2   |  H 3  |  Text3   |  H 4  |  Text4   |  H
A web page presents the user with all messages flagged with 'H'. User 
checks messages 1,3 and 4 and submits form.
(i.e. approved=1&approved=3&approved=4)
After performing postgreSQL update, rows 1, 3 and 4 would be updated to:
mid | message | status
----+---------+------- 1  |  Text1   |  A 2  |  Text2   |  H 3  |  Text3   |  A 4  |  Text4   |  A
I have never written a plpgsql function, but tried:

CREATE OR REPLACE FUNCTION update_messages(approved integer) RETURNS 
integer AS
$body$
DECLAREnew_status varchar;new_sample record;

BEGINnew_status := 'A';
FOR new_sample IN SELECT * FROM message_table WHERE status='H' ORDER BY 
mid LOOP UPDATE message_table SET status = new_status WHERE mid = approved;END LOOP;
RETURN 1;
END;
$body$
LANGUAGE 'plpgsql' VOLATILE CALLED ON NULL INPUT SECURITY INVOKER;
I call the function with:
SELECT update_messages(<xsp-request:get-parameter name="approved"/>);

I'm using apache cocoon, which is why you see the variable placeholder: 
<xsp-request:get-parameter name="approved"/>);

Unfortunately, the function only updates the first value submitted (mid 
1), and doesn't loop through the other two values submitted.

Can someone help this novice from getting ulcers?

Thanks for your help!

Daniel


Re: Multi-row update w. plpgsql function

От
"Owen Jacobson"
Дата:
Daniel Hertz wrote:

> Given a set of checkbox values that are submitted through an
> html form,
> how do you loop through the submitted values to update more
> than one row
> in a table?
>
> Imagine a table called 'message_table':
>
> mid | message | status
> ----+---------+-------
>   1  |  Text1   |  H
>   2  |  Text2   |  H
>   3  |  Text3   |  H
>   4  |  Text4   |  H
>
> A web page presents the user with all messages flagged with 'H'. User
> checks messages 1,3 and 4 and submits form.
> (i.e. approved=1&approved=3&approved=4)
>
> After performing postgreSQL update, rows 1, 3 and 4 would be
> updated to:
>
> mid | message | status
> ----+---------+-------
>   1  |  Text1   |  A
>   2  |  Text2   |  H
>   3  |  Text3   |  A
>   4  |  Text4   |  A

BEGIN;
UPDATE message_table SET status = 'A' WHERE mid = 1;
UPDATE message_table SET status = 'A' WHERE mid = 3;
UPDATE message_table SET status = 'A' WHERE mid = 4;
COMMIT;

would do that.  Have your application generate an appropriate UPDATE line for each "approved" entry in the form data,
wrapit in a transaction, and away you go. 

> I have never written a plpgsql function, but tried:
>
> CREATE OR REPLACE FUNCTION update_messages(approved integer) RETURNS
> integer AS
> $body$
> DECLARE
>  new_status varchar;
>  new_sample record;
>
> BEGIN
>  new_status := 'A';
>
>  FOR new_sample IN SELECT * FROM message_table WHERE
> status='H' ORDER BY
> mid LOOP

1.  No need for ORDER BY here, we're not doing anything user-visible or order-dependent with the data, so it's a waste
ofCPU time. 
2.  You're not using new_sample for anything, just retrieving it.

>   UPDATE message_table SET status = new_status
>   WHERE mid = approved;

Consider that you can only pass a single value to an INTEGER parameter ("approved"); this will repeatedly update a
singleentry where mid = approved.  You could simplify the function as written to 

CREATE OR REPLACE FUNCTION update_messages (INTEGER) RETURNS VOID AS $$ UPDATE message_table SET status = 'A' WHERE mid
=$1; 
$$ LANGUAGE SQL;

>  END LOOP;
>
>  RETURN 1;
> END;
> $body$
> LANGUAGE 'plpgsql' VOLATILE CALLED ON NULL INPUT SECURITY INVOKER;
>
> I call the function with:
> SELECT update_messages(<xsp-request:get-parameter name="approved"/>);
>
> I'm using apache cocoon, which is why you see the variable
> placeholder:
> <xsp-request:get-parameter name="approved"/>);

I'm not familiar with Cocoon, but I'd expect that to return only the first of the "approved" values from the HTTP
request. If you add logging to the stored function (RAISE NOTICE 'approved: %', approved; near the start of the
function,for instance) and tell PostgreSQL to store the logs, you can see what values your function is actually being
calledwith. 

What you really want to do is begin a transaction, loop over all the values of approved present in the form data and
call(the rewritten version of) update_messages for each one, then commit the transaction. 

-Owen


Re: Multi-row update w. plpgsql function

От
Aaron Koning
Дата:
Owen makes a good point. Check that you are using the [] in the HTML input variable for the checkboxes. Like:

<input type="checkbox" name="approved[]" value="1" /> 1 <br/>
<input type="checkbox" name="approved[]" value="2" /> 2 <br/>
<input type="checkbox" name="approved[]" value="3" /> 3 <br/>
<input type="checkbox" name="approved[]" value="4" /> 4 <br/>

Aaron

On 12/13/05, Owen Jacobson <ojacobson@osl.com> wrote:
Daniel Hertz wrote:

> Given a set of checkbox values that are submitted through an
> html form,
> how do you loop through the submitted values to update more
> than one row
> in a table?
>
> Imagine a table called 'message_table':
>
> mid | message | status
> ----+---------+-------
>   1  |  Text1   |  H
>   2  |  Text2   |  H
>   3  |  Text3   |  H
>   4  |  Text4   |  H
>
> A web page presents the user with all messages flagged with 'H'. User
> checks messages 1,3 and 4 and submits form.
> (i.e. approved=1&approved=3&approved=4)
>
> After performing postgreSQL update, rows 1, 3 and 4 would be
> updated to:
>
> mid | message | status
> ----+---------+-------
>   1  |  Text1   |  A
>   2  |  Text2   |  H
>   3  |  Text3   |  A
>   4  |  Text4   |  A

BEGIN;
UPDATE message_table SET status = 'A' WHERE mid = 1;
UPDATE message_table SET status = 'A' WHERE mid = 3;
UPDATE message_table SET status = 'A' WHERE mid = 4;
COMMIT;

would do that.  Have your application generate an appropriate UPDATE line for each "approved" entry in the form data, wrap it in a transaction, and away you go.

> I have never written a plpgsql function, but tried:
>
> CREATE OR REPLACE FUNCTION update_messages(approved integer) RETURNS
> integer AS
> $body$
> DECLARE
>  new_status varchar;
>  new_sample record;
>
> BEGIN
>  new_status := 'A';
>
>  FOR new_sample IN SELECT * FROM message_table WHERE
> status='H' ORDER BY
> mid LOOP

1.  No need for ORDER BY here, we're not doing anything user-visible or order-dependent with the data, so it's a waste of CPU time.
2.  You're not using new_sample for anything, just retrieving it.

>   UPDATE message_table SET status = new_status
>   WHERE mid = approved;

Consider that you can only pass a single value to an INTEGER parameter ("approved"); this will repeatedly update a single entry where mid = approved.  You could simplify the function as written to

CREATE OR REPLACE FUNCTION update_messages (INTEGER) RETURNS VOID AS $$
  UPDATE message_table SET status = 'A' WHERE mid = $1;
$$ LANGUAGE SQL;

>  END LOOP;
>
>  RETURN 1;
> END;
> $body$
> LANGUAGE 'plpgsql' VOLATILE CALLED ON NULL INPUT SECURITY INVOKER;
>
> I call the function with:
> SELECT update_messages(<xsp-request:get-parameter name="approved"/>);
>
> I'm using apache cocoon, which is why you see the variable
> placeholder:
> <xsp-request:get-parameter name="approved"/>);

I'm not familiar with Cocoon, but I'd expect that to return only the first of the "approved" values from the HTTP request.  If you add logging to the stored function (RAISE NOTICE 'approved: %', approved; near the start of the function, for instance) and tell PostgreSQL to store the logs, you can see what values your function is actually being called with.

What you really want to do is begin a transaction, loop over all the values of approved present in the form data and call (the rewritten version of) update_messages for each one, then commit the transaction.

-Owen

---------------------------(end of broadcast)---------------------------
TIP 2: Don't 'kill -9' the postmaster

Re: Multi-row update w. plpgsql function

От
Aarni Ruuhimäki
Дата:
Hi,

If your checkboxes are like

input type="checkbox" name="approved" value="1"
input type="checkbox" name="approved" value="2"
input type="checkbox" name="approved" value="3"
input type="checkbox" name="approved" value="4"

and 1, 3 and 4 are checked your form data will be approved=1,3,4

Then you can just say

UPDATE message_table SET status = 'A' WHERE mid IN($approved);

Not a function though.

BR,

Aarni

testing=# SELECT * FROM message_table;mid | message | status
-----+---------+--------  1 | text1   | H  2 | text2   | H  3 | text3   | H  4 | text4   | H
(4 rows)

testing=# UPDATE message_table SET status = 'A' WHERE mid IN(1,3,4);
UPDATE 3
testing=# SELECT * FROM message_table;mid | message | status
-----+---------+--------  2 | text2   | H  1 | text1   | A  3 | text3   | A  4 | text4   | A
(4 rows)

testing=#

On Wednesday 14 December 2005 01:00, Daniel Hertz wrote:
> Given a set of checkbox values that are submitted through an html form,
> how do you loop through the submitted values to update more than one row
> in a table?
>
> Imagine a table called 'message_table':
>
> mid | message | status
> ----+---------+-------
>   1  |  Text1   |  H
>   2  |  Text2   |  H
>   3  |  Text3   |  H
>   4  |  Text4   |  H
>
> A web page presents the user with all messages flagged with 'H'. User
> checks messages 1,3 and 4 and submits form.
> (i.e. approved=1&approved=3&approved=4)
>
> After performing postgreSQL update, rows 1, 3 and 4 would be updated to:
>
> mid | message | status
> ----+---------+-------
>   1  |  Text1   |  A
>   2  |  Text2   |  H
>   3  |  Text3   |  A
>   4  |  Text4   |  A
>
> I have never written a plpgsql function, but tried:
>
> CREATE OR REPLACE FUNCTION update_messages(approved integer) RETURNS
> integer AS
> $body$
> DECLARE
>  new_status varchar;
>  new_sample record;
>
> BEGIN
>  new_status := 'A';
>
>  FOR new_sample IN SELECT * FROM message_table WHERE status='H' ORDER BY
> mid LOOP
>   UPDATE message_table SET status = new_status
>   WHERE mid = approved;
>  END LOOP;
>
>  RETURN 1;
> END;
> $body$
> LANGUAGE 'plpgsql' VOLATILE CALLED ON NULL INPUT SECURITY INVOKER;
>
> I call the function with:
> SELECT update_messages(<xsp-request:get-parameter name="approved"/>);
>
> I'm using apache cocoon, which is why you see the variable placeholder:
> <xsp-request:get-parameter name="approved"/>);
>
> Unfortunately, the function only updates the first value submitted (mid
> 1), and doesn't loop through the other two values submitted.
>
> Can someone help this novice from getting ulcers?
>
> Thanks for your help!
>
> Daniel
>
> ---------------------------(end of broadcast)---------------------------
> TIP 2: Don't 'kill -9' the postmaster

--
Aarni Ruuhimäki
--------------
This is a bugfree broadcast to you
from **Kmail**
on **Fedora Core** linux system
--------------


Re: Multi-row update w. plpgsql function

От
"Magnus Hagander"
Дата:
> > Imagine a table called 'message_table':
> >
> > mid | message | status
> > ----+---------+-------
> >   1  |  Text1   |  H
> >   2  |  Text2   |  H
> >   3  |  Text3   |  H
> >   4  |  Text4   |  H
> >
> > A web page presents the user with all messages flagged with
> 'H'. User
> > checks messages 1,3 and 4 and submits form.
> > (i.e. approved=1&approved=3&approved=4)
> >
> > After performing postgreSQL update, rows 1, 3 and 4 would
> be updated
> > to:
> >
> > mid | message | status
> > ----+---------+-------
> >   1  |  Text1   |  A
> >   2  |  Text2   |  H
> >   3  |  Text3   |  A
> >   4  |  Text4   |  A
>
> BEGIN;
> UPDATE message_table SET status = 'A' WHERE mid = 1; UPDATE
> message_table SET status = 'A' WHERE mid = 3; UPDATE
> message_table SET status = 'A' WHERE mid = 4; COMMIT;
>
> would do that.  Have your application generate an appropriate
> UPDATE line for each "approved" entry in the form data, wrap
> it in a transaction, and away you go.

It would probably be even more efficient to do:
UPDATE message_table SET status = 'A' WHERE mid IN (1,3,4)

and then use client code to generate the comma-separated list of ids.
(Don't forget to make sure they are actual integers so you don't get a
sql injection from it - I don't think parametrised queries can deal with
comma lists)

//Magnus


Re: Multi-row update w. plpgsql function

От
Daniel Hertz
Дата:
Aaron Koning wrote:
> Owen makes a good point. Check that you are using the [] in the HTML input
> variable for the checkboxes. Like:
>
> <input type="checkbox" name="approved[]" value="1" /> 1 <br/>
> <input type="checkbox" name="approved[]" value="2" /> 2 <br/>
> <input type="checkbox" name="approved[]" value="3" /> 3 <br/>
> <input type="checkbox" name="approved[]" value="4" /> 4 <br/>
>
> Aaron
>
> On 12/13/05, Owen Jacobson <ojacobson@osl.com> wr
>> I'm not familiar with Cocoon, but I'd expect that to return only the first
>> of the "approved" values from the HTTP request.  If you add logging to the
>> stored function (RAISE NOTICE 'approved: %', approved; near the start of the
>> function, for instance) and tell PostgreSQL to store the logs, you can see
>> what values your function is actually being called with.
>>
>> What you really want to do is begin a transaction, loop over all the
>> values of approved present in the form data and call (the rewritten version
>> of) update_messages for each one, then commit the transaction.
>>
>> -Owen

Thank you all, so much, for taking the time to help me out. Especially 
as a beginner, where coding IS rocket science.

On the general board, Aaron mentioned:

UPDATE message_table SET status = 'A' WHERE mid IN (1,2,3);

which seems very succinct and economical. I'm gonna have a go at parsing the query string using XSLT, substituting the
variablefor:
 

UPDATE message_table SET status = 'A' WHERE mid IN ($query_values_here);

Again, thanks for the help,

Daniel