[SQL] default value for select?

2005-05-09 Thread Mark Fenbers




I want to update a column in myTable. The value this column is set to
depends on a nested select statement which sometimes returns 0 rows
instead of 1. This is a problem since the column I'm trying to update
is set to refuse nulls. Here's a sample:

update myTable set myColumn = (Select altColumn from altTable where
altColumn != 'XXX' limit 1) where myColumn = 'XXX';

MyColumn cannot accept nulls, but sometimes "Select altColumn ..."
returns 0 rows, and thus, the query fails. 

Is there a way to set a default value to be inserted into myColumn if
and when "select altColumn ..." returns zero rows?

Mark


begin:vcard
fn:Mark Fenbers
n:Fenbers;Mark
org:DoC/NOAA/NWS/OHRFC
adr:;;1901 South SR 134;Wilmington;OH;45177-9708;USA
email;internet:[EMAIL PROTECTED]
title:Sr. HAS Meteorologist
tel;work:937-383-0430 x246
x-mozilla-html:TRUE
url:http://weather.gov/ohrfc
version:2.1
end:vcard


---(end of broadcast)---
TIP 8: explain analyze is your friend


Re: [SQL] default value for select?

2005-05-09 Thread Tony Wasson
On 5/9/05, Mark Fenbers [EMAIL PROTECTED] wrote:
  I want to update a column in myTable.  The value this column is set to
 depends on a nested select statement which sometimes returns 0 rows instead
 of 1.  This is a problem since the column I'm trying to update is set to
 refuse nulls.  Here's a sample:
  
  update myTable set myColumn = (Select altColumn from altTable where
 altColumn != 'XXX' limit 1) where myColumn = 'XXX';
  
  MyColumn cannot accept nulls, but sometimes Select altColumn ... returns
 0 rows, and thus, the query fails.  
  
  Is there a way to set a default value to be inserted into myColumn if and
 when select altColumn ... returns zero rows?
  
  Mark

Mark, 
You can work around this by using a CASE statement. In this case, test
for a NULL from your subquery. This is not elegant at all, but it
should do what you are wanting.

update myTable set myColumn = (CASE
  WHEN (Select altColumn from altTable where  altColumn != 'XXX'
limit 1) IS NULL
THEN 'some default value'
  ELSE (Select altColumn from altTable where  altColumn != 'XXX' limit 1)
  END)
where myColumn = 'XXX';

Hope this helps...
Tony

---(end of broadcast)---
TIP 5: Have you checked our extensive FAQ?

   http://www.postgresql.org/docs/faq


Re: [SQL] default value for select?

2005-05-09 Thread Keith Worthington
On Mon, 09 May 2005 12:57:41 -0400, Mark Fenbers wrote
 I want to update a column in myTable. The value this column is set 
 todepends on a nested select statement which sometimes returns 0 
 rowsinstead of 1. This is a problem since the column I'm trying to 
 updateis set to refuse nulls. Here's a sample:
 
 update myTable set myColumn = (Select altColumn from altTable 
 wherealtColumn != 'XXX' limit 1) where myColumn = 'XXX';
 
 MyColumn cannot accept nulls, but sometimes Select altColumn 
 ...returns 0 rows, and thus, the query fails.
 
 Is there a way to set a default value to be inserted into myColumn 
 ifand when select altColumn ... returns zero rows?
 
 Mark

Mark,

I do not know if it will work but I would try the COALESCE function.
http://www.postgresql.org/docs/8.0/interactive/functions-conditional.html

Kind Regards,
Keith

---(end of broadcast)---
TIP 8: explain analyze is your friend


Re: [SQL] default value for select?

2005-05-09 Thread Philip Hallstrom
I want to update a column in myTable.  The value this column is set to depends 
on a
nested select statement which sometimes returns 0 rows instead of 1.  This is a
problem since the column I'm trying to update is set to refuse nulls.  Here's a
sample:
update myTable set myColumn = (Select altColumn from altTable where altColumn !=
'XXX' limit 1) where myColumn = 'XXX';
MyColumn cannot accept nulls, but sometimes Select altColumn ... returns 0 rows,
and thus, the query fails. 

Is there a way to set a default value to be inserted into myColumn if and when
select altColumn ... returns zero rows?
COALESCE(value [, ...])
The COALESCE function returns the first of its arguments that is not null. 
Null is returned only if all arguments are null. This is often useful to 
substitute a default value for null values when data is retrieved for 
display, for example:

SELECT COALESCE(description, short_description, '(none)') ...
Like a CASE expression, COALESCE will not evaluate arguments that are not 
needed to determine the result; that is, arguments to the right of the 
first non-null argument are not evaluated.

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