473,799 Members | 2,822 Online
Bytes | Software Development & Data Engineering Community
+ Post

Home Posts Topics Members FAQ

Queries slow from within plpgsql

I've been trying to create functions with postgres, but it seems that
queries run within a function take wayyy too long to complete. The
increased time seems to be in the actual queries, not function call
overhead or something, but I can't for the life of me figure out why
it's slower like this. I've simplified it to what you see below.

Any insight would be *much* appreciated. Thanks!
- Dave
dave=# SELECT * FROM testfunc('V2P 6H3');
testfunc
----------
1
(1 row)

Time: 1120.634 ms
dave=# SELECT * FROM zips WHERE zip='V2P 6H3';
city | state | zip | areacode |
county | time_zone | dst | country | latitude | longitude
| zip_type | fips
-----------------------------------+-------+---------+----------
+---------------------------+-----------+-----+---------+----------
+-----------+----------+-------
Chilliwack | BC | V2P 6H3 | 604 |
| PST | Y | C | 49.1757 | 121.9301
| |
(1 row)

Time: 0.895 ms
dave=# SELECT * FROM testfunc('V2P 6H3');
testfunc
----------
1
(1 row)

Time: 1287.793 ms
dave=# \df+ testfunc

List of functions
Result data type | Schema | Name | Argument data types | Owner |
Language | Source code
| Description
------------------+--------+----------+---------------------+-------
+----------
+-----------------------------------------------------------------------
---------------+-------------
integer | public | testfunc | text | dave |
plpgsql | DECLARE zip1 RECORD; BEGIN SELECT INTO zip1 * FROM zips
WHERE zip=$1; RETURN 1; END; |
(1 row)

dave=# \d zips
Table "public.zip s"
Column | Type | Modifiers
-----------+---------------+-----------------------------
city | character(33) |
state | character(2) |
zip | character(7) | not null default ''::bpchar
areacode | character(3) |
county | character(25) |
time_zone | character(5) |
dst | character(1) |
country | character(1) |
latitude | numeric(6,4) |
longitude | numeric(7,4) |
zip_type | character(1) |
fips | character(5) |
Indexes:
"zip_idx" btree (zip)

dave=# select version();
version
------------------------------------------------------------------------
--------------------------------------------------
PostgreSQL 7.4.2 on i686-pc-linux-gnu, compiled by GCC gcc (GCC) 3.3.2
20031218 (Gentoo Linux 3.3.2-r5, propolice-3.3-7)
(1 row)
---------------------------(end of broadcast)---------------------------
TIP 6: Have you searched our list archives?

http://archives.postgresql.org

Nov 23 '05 #1
2 1862
David Boone <da**@iboone.ne t> wrote:
I've been trying to create functions with postgres, but it seems that
queries run within a function take wayyy too long to complete. The
increased time seems to be in the actual queries, not function call
overhead or something, but I can't for the life of me figure out why
it's slower like this. I've simplified it to what you see below.

Any insight would be *much* appreciated. Thanks!
- Dave
dave=# SELECT * FROM testfunc('V2P 6H3');
testfunc
----------
1
(1 row)

Time: 1120.634 ms
dave=# SELECT * FROM zips WHERE zip='V2P 6H3';
city | state | zip | areacode |
county | time_zone | dst | country | latitude | longitude
| zip_type | fips
-----------------------------------+-------+---------+----------
+---------------------------+-----------+-----+---------+----------
+-----------+----------+-------
Chilliwack | BC | V2P 6H3 | 604 |
| PST | Y | C | 49.1757 | 121.9301
| |
(1 row)

Time: 0.895 ms
dave=# SELECT * FROM testfunc('V2P 6H3');
testfunc
----------
1
(1 row)

Time: 1287.793 ms
dave=# \df+ testfunc

List of functions
Result data type | Schema | Name | Argument data types | Owner |
Language | Source code
| Description
------------------+--------+----------+---------------------+-------
+----------
+-----------------------------------------------------------------------
---------------+-------------
integer | public | testfunc | text | dave |
plpgsql | DECLARE zip1 RECORD; BEGIN SELECT INTO zip1 * FROM zips
WHERE zip=$1; RETURN 1; END; |
(1 row)
This function is not very well optimized ... it doesn't even seem to work
correctly.

Why not just create an SQL function that has the SQL you need in it?

Why? Because of a few things I've learned in my own function writing:
1) plpgsql is slower than stored SQL
2) When you call SQL in plpgsql, you invoke overhead of the SQL parser in
addition to the plpgsql parser. If all you're doing is calling SQL,
this is a waste.
3) Try declaring zip1 zips%ROWTYPE ... I think that will speed things up
as well.

See what performance you get with:

CREATE FUNCTION testfunc2(TEXT)
RETURNS zips
AS '
SELECT * FROM zips WHERE zip = $1;
' LANGUAGE SQL;

HTH

dave=# \d zips
Table "public.zip s"
Column | Type | Modifiers
-----------+---------------+-----------------------------
city | character(33) |
state | character(2) |
zip | character(7) | not null default ''::bpchar
areacode | character(3) |
county | character(25) |
time_zone | character(5) |
dst | character(1) |
country | character(1) |
latitude | numeric(6,4) |
longitude | numeric(7,4) |
zip_type | character(1) |
fips | character(5) |
Indexes:
"zip_idx" btree (zip)

dave=# select version();
version
------------------------------------------------------------------------
--------------------------------------------------
PostgreSQL 7.4.2 on i686-pc-linux-gnu, compiled by GCC gcc (GCC) 3.3.2
20031218 (Gentoo Linux 3.3.2-r5, propolice-3.3-7)
(1 row)
---------------------------(end of broadcast)---------------------------
TIP 6: Have you searched our list archives?

http://archives.postgresql.org

--
Bill Moran
Potential Technologies
http://www.potentialtech.com

---------------------------(end of broadcast)---------------------------
TIP 2: you can get off all lists at once with the unregister command
(send "unregister YourEmailAddres sHere" to ma*******@postg resql.org)

Nov 23 '05 #2
David Boone <da**@iboone.ne t> writes:
I've been trying to create functions with postgres, but it seems that
queries run within a function take wayyy too long to complete. The
increased time seems to be in the actual queries, not function call
overhead or something, but I can't for the life of me figure out why
it's slower like this.


The problem here looks to be that you've declared the function parameter
as "text" while the table column is "char(7)". When you write
select ... where zip = 'V2P 6H3';
the unadorned literal is taken to be char(7) to match the compared-to
column, but in the function case the datatype of $1 is predetermined,
and so
select ... where zip = $1;
involves a cross-data-type-comparison ... which is non-indexable
in current releases. (There's a fix in place for 7.5.) Either
change the declared type of the function parameter, or put a cast
into the body of the function.

regards, tom lane

---------------------------(end of broadcast)---------------------------
TIP 1: subscribe and unsubscribe commands go to ma*******@postg resql.org

Nov 23 '05 #3

This thread has been closed and replies have been disabled. Please start a new discussion.

Similar topics

2
1989
by: Josué Maldonado | last post by:
Hi list, That's the question, anyone knows a way to do that? Thanks in advance, Josue Maldonado.
1
2477
by: Rajesh Kumar Mallah | last post by:
Hi, profile_row profile_master%ROWTYPE; in a plpgsql function gives the error below tradein_clients=# SELECT general.create_accounts(); WARNING: plpgsql: ERROR during compile of create_accounts near line 8
13
5908
by: Anton.Nikiforov | last post by:
Hello everybody! Does someone know how to build hierarchical queries to the postgresql? I have a table with tree in it (id, parent) and need to find a way from any point of the tree to any other point. And i would like to have a list of all steps from point A to point B to make some changes on each step (this is required by the algorythm). Here is an example:
7
5271
by: Jim Crate | last post by:
I have a couple queries in a PL/PGSQL function which execute very slowly (around one minute each) which execute in .5 second when not executed from within the function. Is there any way to determine why this is happening? I couldn't figure out how to run EXPLAIN ANALYZE from within the function. The queries aren't very complicated. Here is an example query and plan. About 240K rows in x_rbl_ips, 7.5M rows in filter_ips. explain...
4
4974
by: Bill Moran | last post by:
I've got a bit of a strange problem that's causing me some MAJOR headaches. I'm developing the server-side of a large database application in PostgreSQL. This consists of a C daemon, and a LOT of stored functions in the database. I'm developing this in conjunction with another company, who is developing the the client side. I've got a 7.4 server that I'm developing on, and once a day I push my changes up to a common
14
5838
by: Karl O. Pinc | last post by:
Hi, Thought perhaps some other eyes than mine can tell if I'm doing something wrong here or if there's a bug somewhere. I've never passed a ROWTYPE varaible to a function but I don't see where the problem is. I keep getting errors like (the first is my debug output): NOTICE: last cycle is: 11 WARNING: Error occurred while executing PL/pgSQL function
6
329
by: David Boone | last post by:
I've been trying to create functions with postgres, but it seems that queries run within a function take wayyy too long to complete. The increased time seems to be in the actual queries, not function call overhead or something, but I can't for the life of me figure out why it's slower like this. I've simplified it to what you see below. Any insight would be *much* appreciated. Thanks! - Dave
0
1481
by: sripathy sena | last post by:
Hi, I am trying to install OPenacs with postgres 7.4.3 as the database. The openacs requires plpgsql to be installed. When I try to do this by running "CREATELANG plpgsql template1". I get a message file plpgsql not found in lib directory.
14
2472
by: google | last post by:
I am creating a new database for use within our company, that I'd like to make reasonably secure (short of a true server based solution). The back-end of a non-server based database seems to be the biggest security hole, due to the ease of opening, linking, and/or importing raw data directly from the back-end database. I've read information that indicates that locking down the back-end tables to the owner, then using RWOP queries in the...
0
9689
marktang
by: marktang | last post by:
ONU (Optical Network Unit) is one of the key components for providing high-speed Internet services. Its primary function is to act as an endpoint device located at the user's premises. However, people are often confused as to whether an ONU can Work As a Router. In this blog post, we’ll explore What is ONU, What Is Router, ONU & Router’s main usage, and What is the difference between ONU and Router. Let’s take a closer look ! Part I. Meaning of...
0
9550
by: Hystou | last post by:
Most computers default to English, but sometimes we require a different language, especially when relocating. Forgot to request a specific language before your computer shipped? No problem! You can effortlessly switch the default language on Windows 10 without reinstalling. I'll walk you through it. First, let's disable language synchronization. With a Microsoft account, language settings sync across devices. To prevent any complications,...
0
10495
Oralloy
by: Oralloy | last post by:
Hello folks, I am unable to find appropriate documentation on the type promotion of bit-fields when using the generalised comparison operator "<=>". The problem is that using the GNU compilers, it seems that the internal comparison operator "<=>" tries to promote arguments from unsigned to signed. This is as boiled down as I can make it. Here is my compilation command: g++-12 -std=c++20 -Wnarrowing bit_field.cpp Here is the code in...
0
10269
jinu1996
by: jinu1996 | last post by:
In today's digital age, having a compelling online presence is paramount for businesses aiming to thrive in a competitive landscape. At the heart of this digital strategy lies an intricately woven tapestry of website design and digital marketing. It's not merely about having a website; it's about crafting an immersive digital experience that captivates audiences and drives business growth. The Art of Business Website Design Your website is...
1
10248
by: Hystou | last post by:
Overview: Windows 11 and 10 have less user interface control over operating system update behaviour than previous versions of Windows. In Windows 11 and 10, there is no way to turn off the Windows Update option using the Control Panel or Settings app; it automatically checks for updates and installs any it finds, whether you like it or not. For most users, this new feature is actually very convenient. If you want to control the update process,...
1
7573
isladogs
by: isladogs | last post by:
The next Access Europe User Group meeting will be on Wednesday 1 May 2024 starting at 18:00 UK time (6PM UTC+1) and finishing by 19:30 (7.30PM). In this session, we are pleased to welcome a new presenter, Adolph Dupré who will be discussing some powerful techniques for using class modules. He will explain when you may want to use classes instead of User Defined Types (UDT). For example, to manage the data in unbound forms. Adolph will...
0
5469
by: TSSRALBI | last post by:
Hello I'm a network technician in training and I need your help. I am currently learning how to create and manage the different types of VPNs and I have a question about LAN-to-LAN VPNs. The last exercise I practiced was to create a LAN-to-LAN VPN between two Pfsense firewalls, by using IPSEC protocols. I succeeded, with both firewalls in the same network. But I'm wondering if it's possible to do the same thing, with 2 Pfsense firewalls...
0
5597
by: adsilva | last post by:
A Windows Forms form does not have the event Unload, like VB6. What one acts like?
1
4148
by: 6302768590 | last post by:
Hai team i want code for transfer the data from one system to another through IP address by using C# our system has to for every 5mins then we have to update the data what the data is updated we have to send another system

By using Bytes.com and it's services, you agree to our Privacy Policy and Terms of Use.

To disable or enable advertisements and analytics tracking please visit the manage ads & tracking page.