Thread: Expr Abbreviations/Functions?
I find myself frequently typing (postgresql-6.5.1) the following: SELECT * FROM table WHERE (f1 ~* 'foo' OR f2 ~* 'foo' OR f3 ~* 'foo'); Can "CREATE FUNCTION" be used? Something like CREATE FUNCTION f(string) RETURNS bool AS '(f1 ~* '$1' OR f2 ~* '$1' ...)'; and then type SELECT * FROM table WHERE f('foo'); I tried to define such a function, but encountered two problems: o It didn't "accept" the function's definition o Syntax errors (apostrophes need escaping ... I tried mixing quotes and apostrophes, also using '\' chars ... nothing seemedto work) I know that I can define VIEWs (and FUNCTIONs) that contain a specific SELECT statement, but I'd prefer to have definitions of just the repeating expressions. Another thing I'd like to "abbreviate" is the second phrase in SELECTs. E.g, SELECT x FROM table; instead of SELECT x1,x2,x3 FROM table; where 'x' is somehow equivalent to 'x1,x2,x3'. I read the online docs and searched a few SQL books, but can't seem to find the correct approach. Ideas? Thanks for any help, -Prof Kenneth H Jacker khj@cs.appstate.edu -Computer Science Dept www.cs.appstate.edu/~khj -Appalachian State Univ -Boone, NC 28608 USA
Kenneth, You could merge the fields and search with : select * from tablex where lower(f1||f2||f3) ~ 'foo'; Troy Troy Korjuslommi Tksoft OY, Inc. tjk@tksoft.com Software Development Open Source Solutions Hosting Services > > I find myself frequently typing (postgresql-6.5.1) the following: > > SELECT * FROM table > WHERE (f1 ~* 'foo' OR f2 ~* 'foo' OR f3 ~* 'foo'); > > Can "CREATE FUNCTION" be used? Something like > > CREATE FUNCTION f(string) > RETURNS bool > AS '(f1 ~* '$1' OR f2 ~* '$1' ...)'; > > and then type > > SELECT * FROM table WHERE f('foo'); > > > I tried to define such a function, but encountered two problems: > > o It didn't "accept" the function's definition > > o Syntax errors (apostrophes need escaping ... I tried mixing quotes > and apostrophes, also using '\' chars ... nothing seemed to work) > > > I know that I can define VIEWs (and FUNCTIONs) that contain a specific > SELECT statement, but I'd prefer to have definitions of just the > repeating expressions. > > > Another thing I'd like to "abbreviate" is the second phrase in > SELECTs. E.g, > > SELECT x FROM table; > > instead of > > SELECT x1,x2,x3 FROM table; > > where 'x' is somehow equivalent to 'x1,x2,x3'. > > > I read the online docs and searched a few SQL books, but can't seem to > find the correct approach. Ideas? > > Thanks for any help, > > -Prof Kenneth H Jacker khj@cs.appstate.edu > -Computer Science Dept www.cs.appstate.edu/~khj > -Appalachian State Univ > -Boone, NC 28608 USA > > > >
At 02:11 +0300 on 25/07/1999, tjk@tksoft.com wrote: > You could merge the fields and search with : > > select * from tablex where lower(f1||f2||f3) ~ 'foo'; Nah. If f1 is 'Narf' and f2 is 'oodp', it will match... Herouth -- Herouth Maoz, Internet developer. Open University of Israel - Telem project http://telem.openu.ac.il/~herutma
Herouth, You're right. If I recall the original question correctly, the "only" real solution would seem to be to define a function to search the appropriate fields. Troy Troy Korjuslommi Tksoft OY, Inc. tjk@tksoft.com Software Development Open Source Solutions Hosting Services > > At 02:11 +0300 on 25/07/1999, tjk@tksoft.com wrote: > > > > You could merge the fields and search with : > > > > select * from tablex where lower(f1||f2||f3) ~ 'foo'; > > Nah. If f1 is 'Narf' and f2 is 'oodp', it will match... > > Herouth > > -- > Herouth Maoz, Internet developer. > Open University of Israel - Telem project > http://telem.openu.ac.il/~herutma > > > >
At 07:52 +0300 on 26/07/1999, tjk@tksoft.com wrote: > If I recall the original question correctly, the > "only" real solution would seem to be to define > a function to search the appropriate fields. Yes. The original question had a conceptual problem. It wanted to abbreviate the expression without the name of the table. This was nonsensical - you can't ask whether id > 3. You can ask whether person.id > 3. Just "id" could be anything in the world. Asking a database to do that is like asking a person to play a flute in vacuum. Another problem was that it implied returning a set of rows. This is not well supported by postgres - and that's a known limitation. The best thing that can be done at the moment is to have a function that accepts the strings as parameters and returns a boolean: CREATE FUNCTION match_three ( text, text, text, text ) RETURNS bool AS ' SELECT (( $1 ~ $4 ) OR ( $2 ~ $4 ) OR ($3 ~ $4)) ' LANGUAGE 'sql'; Then it can be used as: SELECT * FROM table1 WHERE match_three( x1, x2, x3, 'foo' ); Herouth -- Herouth Maoz, Internet developer. Open University of Israel - Telem project http://telem.openu.ac.il/~herutma