Please start any new threads on our new site at https://forums.sqlteam.com. We've got lots of great SQL Server experts to answer whatever question you can come up with.

 All Forums
 General SQL Server Forums
 New to SQL Server Administration
 Default column value

Author  Topic 

bak2127
Starting Member

1 Post

Posted - 2009-10-30 : 14:15:31
I have a table with a DueDate (datetime) column. The users don't always fill in the date in the application so I have been asked to create a default value of getdate()+2. I created a new default in the database and used sp_binddefault to bind the default value to the column. In test when the user leaves the date field blank it still shows up as null in the table.

What do I need to do to get the value to insert into the table?

Thanks in advance,

B

russell
Pyro-ma-ni-yak

5072 Posts

Posted - 2009-10-30 : 14:45:42
[code]ALTER Table YourTable ADD DEFAULT (getdate()+2) FOR DueDate[/code]
Go to Top of Page

jhocutt
Constraint Violating Yak Guru

385 Posts

Posted - 2009-10-30 : 14:45:50
use Northwind
go

-- No column specified for c2 uses the default value
create table tmp (c1 varchar(10), c2 datetime default dateadd(dd, 2, getdate()))
insert into tmp (c1) values ('1')
select * from tmp
drop table tmp
go

-- column specified for c2 bypasses the default value
create table tmp (c1 varchar(10), c2 datetime default dateadd(dd, 2, getdate()))
insert into tmp (c1, c2) values ('2', null)
select * from tmp
drop table tmp
go

-- column specified for c2 bypasses the default value
-- Even using sp_bindefault
CREATE DEFAULT c2fld AS dateadd(dd, 2, getdate())
go
create table tmp (c1 varchar(10), c2 datetime )
EXEC sp_bindefault 'c2fld', 'tmp.[c2]'
insert into tmp (c1, c2) values ('3', null)
select * from tmp
drop table tmp
DROP DEFAULT c2fld

-- to force the value change the insert
create table tmp (c1 varchar(10), c2 datetime default dateadd(dd, 2, getdate()))
declare @x datetime
insert into tmp (c1, c2) values ('4', Coalesce(@x, dateadd(dd, 2, getdate())))
select * from tmp
drop table tmp

-- Or create an instead of insert trigger and leave out the date column on the insert
create table tmp (c1 varchar(10), c2 datetime default dateadd(dd, 2, getdate()))
go
CREATE TRIGGER InsteadTmpInsert on tmp
INSTEAD OF INSERT
AS
BEGIN
INSERT INTO tmp (c1)
SELECT c1
FROM inserted
END
GO
insert into tmp (c1, c2) values ('5', null)
select * from tmp
drop table tmp


"God does not play dice" -- Albert Einstein
"Not only does God play dice, but he sometimes throws them where they cannot be seen."
-- Stephen Hawking
Go to Top of Page
   

- Advertisement -