Re: pl/pgsql question (functions) - Mailing list pgsql-sql
From | Richard Huxton |
---|---|
Subject | Re: pl/pgsql question (functions) |
Date | |
Msg-id | 00a601c0fa34$2b240c40$1001a8c0@archonet.com Whole thread Raw |
In response to | pl/pgsql question (functions) (Kristoff Bonne <kristoff.bonne@skypro.be>) |
Responses |
Re: pl/pgsql question (functions)
|
List | pgsql-sql |
From: "Kristoff Bonne" <kristoff.bonne@skypro.be> > Greetings, > > I am new to pl/pgsqm (I did some SQL programming at school, now 8 years > ago so that part is rusty too ;-)) Kristoff - I know exactly how you feel. If only I'd paid more attention when they were explaining what 17th normal form was... > Anycase, I have a question concerning creating your own functions in > pl/pgsql. > > This is my situation: > > I have two tables: > - 'hosts': containing 'hostname' (primary key) and 'ip_address' (unique > and non null). > - 'aliases': containing 'aliasname' (primary key) and 'hostname'(unique > and non null). > - aliasname.hostname is a foreign reference to hosts.hostname > > Further, I've set up a trigger function in both hosts and aliases; so that > a name cannot be in both tables. You could use a constraint (foreign key) and get PG to do the triggers for you. > So far, so good. > > Now, I would like to create a function 'get_ip_address' that ... euh ... > retrieves an IP-address (one argument: hostname). > - If the hostname is in the table 'hosts', return the corresponding > IP-address. > - If the hostname is in the table 'aliases', return the IP-address of the > corresponding hostname in 'hosts'. > - If the hostname is in neither table, return nothing. Are you sure you want a function here? Have you considered a view which does a UNION of the results from both tables? SELECT ip_addr FROM host_to_ip_view WHERE host='any.box.bigcorp.com'; will be rewritten on the fly and should be at least as fast as using a function. Not sure about ordering of IPs when there are multiple entries though. > (See program below): > > The 'problem' is in the case where the data in in neither field. How do I > program this? > > - If there is no 'RETURN' statement for that case; I get an error > 'function terminated without RETURN'. Yep - if you say you return an IP address you need to return one. > - Just <RETURN>, <RETURN ""> or <RETURN ''> all produce an syntax-error. Not valid as IP addr. > - When I do '<RETURN ret>' (ret being the result of the last query, being > the query in the 'aliases' table; I do NOT get an error; but the function > does return something (an empty row). > > This I don't like for two reasons: > 1/ When you do 'select ... from ... where ...', and the query doesn't > 'find' anything; you get NOTHING (no rows). > > When I do get_ip_addr('something_that_does_not_exist'); I do get > SOMETHING: one row (containing an empty field). > > 2/ When another function uses the "get_ip_addr('some_host')" function; I > cannot use 'IF NOT FOUND ...'; as -even when 'some_host' does not exist, > the function returns something. (hence, the 'IF NOT FOUND' case is never > followed). > > So, does anybody any idea how to 'fix' this? I think you probably want "return NULL" for this case. That's what NULL was invented for and it is easy to test for: myip := get_ip_addr('some_host'); if myip is null then... > For some reason, I get the feeling I have the wrong 'concept' of functions > in pl/pgsql. > I am using functions in the wrong 'way'? No - I think you're on the right track. The difference (if I understand this) is that NOT FOUND is checking for an empty set of records, whereas plpgsql can't return a set of records (at the moment) - you need SQL functions for that. Your options would seem to be: 1. Return NULL and test for that 2. Build a view 3. Rewrite the function as SQL Any of the above should be fine. HTH - Richard Huxton