From markamatte at hotmail.com Wed Dec 3 14:45:24 2008 From: markamatte at hotmail.com (Mark A Matte) Date: Wed, 3 Dec 2008 20:45:24 +0000 Subject: [dba-SQLServer] Imported data not seen In-Reply-To: <57E6E6CA42105A48B977303A2CDC272007ACD7DF3D@WPEXCH22.retail.ad.cmltd.net.au> References: <57E6E6CA42105A48B977303A2CDC272007ACD7DF3D@WPEXCH22.retail.ad.cmltd.net.au> Message-ID: Hello All, In Access if I insert/append records to a table and that table has indexes...records that violate the index are ommitted...but records that do not are put in the table. In SQL the entire statement is terminated. Is there an equivalent proccess in SQL server? Thanks, Mark A. Matte _________________________________________________________________ You live life online. So we put Windows on the web. http://clk.atdmt.com/MRT/go/127032869/direct/01/ From markamatte at hotmail.com Wed Dec 3 14:52:11 2008 From: markamatte at hotmail.com (Mark A Matte) Date: Wed, 3 Dec 2008 20:52:11 +0000 Subject: [dba-SQLServer] Imported data not seen In-Reply-To: References: <57E6E6CA42105A48B977303A2CDC272007ACD7DF3D@WPEXCH22.retail.ad.cmltd.net.au> Message-ID: Forgot to change the subject.,.... And found my answer. Thanks and Sorry. Mark > From: markamatte at hotmail.com > To: dba-sqlserver at databaseadvisors.com > Date: Wed, 3 Dec 2008 20:45:24 +0000 > Subject: Re: [dba-SQLServer] Imported data not seen > > > Hello All, > > In Access if I insert/append records to a table and that table has indexes...records that violate the index are ommitted...but records that do not are put in the table. > > In SQL the entire statement is terminated. Is there an equivalent proccess in SQL server? > > Thanks, > > Mark A. Matte > > > _________________________________________________________________ > You live life online. So we put Windows on the web. > http://clk.atdmt.com/MRT/go/127032869/direct/01/ > _______________________________________________ > dba-SQLServer mailing list > dba-SQLServer at databaseadvisors.com > http://databaseadvisors.com/mailman/listinfo/dba-sqlserver > http://www.databaseadvisors.com > _________________________________________________________________ Send e-mail faster without improving your typing skills. http://windowslive.com/Explore/hotmail?ocid=TXT_TAGLM_WL_hotmail_acq_speed_122008 From erbachs at gmail.com Tue Dec 9 16:56:35 2008 From: erbachs at gmail.com (Steve Erbach) Date: Tue, 9 Dec 2008 16:56:35 -0600 Subject: [dba-SQLServer] Series of Sundays in a query Message-ID: <39cb22f30812091456j3742829aqff524caedaa810bd@mail.gmail.com> Dear Group, In an ASP.NET application I'm writing for work, I'd like to create a work scheduling web form. One section contains a check box list of all employees, another is a radio button list of the different possible shifts to choose from, and a third is a checkbox list of "week beginning" dates. The Supervisor checks off all the employees for a particular shift, selects the shift, and then selects the weeks that those shifts apply. Anyway, I want to display 13 weeks of "week beginning dates like so: _ 12/14/2008 _ 12/21/2008 _ 12/28/2008 _ 1/4/2009 etc. I have a table in which each row represents the starting date of each week for the coming year, but I thought that there might be a SQL query that I could create to generate 13-weeks' worth of week-beginning dates, starting with the Sunday immediately coming up. I searched through Joe Celko's "SQL for Smarties", reading the chapter on temporal data in SQL, but I didn't see anything suitable. Any ideas? The brute force approach is a 13-query UNION something like this: SELECT DATEADD(day, 8 - DATEPART(weekday, GETDATE()), GETDATE()) AS WeekBeginning UNION SELECT DATEADD(day, 15 - DATEPART(weekday, GETDATE()), GETDATE()) AS WeekBeginning UNION SELECT DATEADD(day, 22 - DATEPART(weekday, GETDATE()), GETDATE()) AS WeekBeginning UNION etc. ...but this seems TOO brute-forcish. Regards, Steve Erbach Neenah, WI http://www.TheTownCrank.com From davidmcafee at gmail.com Tue Dec 9 17:56:42 2008 From: davidmcafee at gmail.com (David McAfee) Date: Tue, 9 Dec 2008 15:56:42 -0800 Subject: [dba-SQLServer] Series of Sundays in a query In-Reply-To: <39cb22f30812091456j3742829aqff524caedaa810bd@mail.gmail.com> References: <39cb22f30812091456j3742829aqff524caedaa810bd@mail.gmail.com> Message-ID: <8786a4c00812091556p67d49abekb8d9d25194562019@mail.gmail.com> I don't know if is any better, but you can create a udf such as: CREATE FUNCTION udfWeekBegins (@StartDate AS DATETIME, @NumOfWks AS INT) RETURNS @ListTable TABLE (WeekBeginning DATETIME) AS BEGIN DECLARE @LoopDate AS DATETIME SET @LoopDate = @StartDate WHILE @LoopDate < DATEADD(wk, at NumOfWks, at StartDate) BEGIN INSERT INTO @ListTable(WeekBeginning) SELECT @LoopDate SET @LoopDate = DATEADD(dd,7, at LoopDate) END RETURN END Then call it as such: SELECT WeekBeginning FROM dbo.udfWeekBegins('12/08/2008',13) --This returns the next 13 weeks from the date entered, not the next 13 Sundays or like this: DECLARE @StartWeek AS DATETIME SET @StartWeek = DATEADD(day, 8 - DATEPART(weekday, GETDATE()), GETDATE()) SELECT * FROM dbo.udfWeekBegins ( @StartWeek, 13) ResultSet: 2008-12-14 15:55:06.943 2008-12-21 15:55:06.943 2008-12-28 15:55:06.943 2009-01-04 15:55:06.943 2009-01-11 15:55:06.943 2009-01-18 15:55:06.943 2009-01-25 15:55:06.943 2009-02-01 15:55:06.943 2009-02-08 15:55:06.943 2009-02-15 15:55:06.943 2009-02-22 15:55:06.943 2009-03-01 15:55:06.943 2009-03-08 15:55:06.943 On Tue, Dec 9, 2008 at 2:56 PM, Steve Erbach wrote: > > Dear Group, > > In an ASP.NET application I'm writing for work, I'd like to create a > work scheduling web form. One section contains a check box list of all > employees, another is a radio button list of the different possible > shifts to choose from, and a third is a checkbox list of "week > beginning" dates. The Supervisor checks off all the employees for a > particular shift, selects the shift, and then selects the weeks that > those shifts apply. > > Anyway, I want to display 13 weeks of "week beginning dates like so: > > _ 12/14/2008 > _ 12/21/2008 > _ 12/28/2008 > _ 1/4/2009 > etc. > > I have a table in which each row represents the starting date of each > week for the coming year, but I thought that there might be a SQL > query that I could create to generate 13-weeks' worth of > week-beginning dates, starting with the Sunday immediately coming up. > > I searched through Joe Celko's "SQL for Smarties", reading the chapter > on temporal data in SQL, but I didn't see anything suitable. > > Any ideas? The brute force approach is a 13-query UNION something like this: > > SELECT DATEADD(day, 8 - DATEPART(weekday, GETDATE()), GETDATE()) AS > WeekBeginning > UNION > SELECT DATEADD(day, 15 - DATEPART(weekday, GETDATE()), GETDATE()) AS > WeekBeginning > UNION > SELECT DATEADD(day, 22 - DATEPART(weekday, GETDATE()), GETDATE()) AS > WeekBeginning > UNION > etc. > > ...but this seems TOO brute-forcish. > > Regards, > > Steve Erbach > Neenah, WI > http://www.TheTownCrank.com > _______________________________________________ > dba-SQLServer mailing list > dba-SQLServer at databaseadvisors.com > http://databaseadvisors.com/mailman/listinfo/dba-sqlserver > http://www.databaseadvisors.com > From ab-mi at post3.tele.dk Tue Dec 9 18:07:28 2008 From: ab-mi at post3.tele.dk (Asger Blond) Date: Wed, 10 Dec 2008 01:07:28 +0100 Subject: [dba-SQLServer] Series of Sundays in a query In-Reply-To: <39cb22f30812091456j3742829aqff524caedaa810bd@mail.gmail.com> Message-ID: <000001c95a5b$4a4d3f30$2301a8c0@AB> You could use a table variable and a loop like this: DECLARE @WeekBeginning datetime DECLARE @i int DECLARE @t table(WeekBeginning char(10)) SET @i=1 WHILE @i < 91 BEGIN SET @i = @i + 7 INSERT @t VALUES (CONVERT(char(10),GETDATE() + @i,101)) END SELECT WeekBeginning FROM @t HTH Asger -----Oprindelig meddelelse----- Fra: dba-sqlserver-bounces at databaseadvisors.com [mailto:dba-sqlserver-bounces at databaseadvisors.com] P? vegne af Steve Erbach Sendt: 9. december 2008 23:57 Til: Discussion concerning MS SQL Server Emne: [dba-SQLServer] Series of Sundays in a query Dear Group, In an ASP.NET application I'm writing for work, I'd like to create a work scheduling web form. One section contains a check box list of all employees, another is a radio button list of the different possible shifts to choose from, and a third is a checkbox list of "week beginning" dates. The Supervisor checks off all the employees for a particular shift, selects the shift, and then selects the weeks that those shifts apply. Anyway, I want to display 13 weeks of "week beginning dates like so: _ 12/14/2008 _ 12/21/2008 _ 12/28/2008 _ 1/4/2009 etc. I have a table in which each row represents the starting date of each week for the coming year, but I thought that there might be a SQL query that I could create to generate 13-weeks' worth of week-beginning dates, starting with the Sunday immediately coming up. I searched through Joe Celko's "SQL for Smarties", reading the chapter on temporal data in SQL, but I didn't see anything suitable. Any ideas? The brute force approach is a 13-query UNION something like this: SELECT DATEADD(day, 8 - DATEPART(weekday, GETDATE()), GETDATE()) AS WeekBeginning UNION SELECT DATEADD(day, 15 - DATEPART(weekday, GETDATE()), GETDATE()) AS WeekBeginning UNION SELECT DATEADD(day, 22 - DATEPART(weekday, GETDATE()), GETDATE()) AS WeekBeginning UNION etc. ...but this seems TOO brute-forcish. Regards, Steve Erbach Neenah, WI http://www.TheTownCrank.com _______________________________________________ dba-SQLServer mailing list dba-SQLServer at databaseadvisors.com http://databaseadvisors.com/mailman/listinfo/dba-sqlserver http://www.databaseadvisors.com From erbachs at gmail.com Tue Dec 9 19:03:55 2008 From: erbachs at gmail.com (Steve Erbach) Date: Tue, 9 Dec 2008 19:03:55 -0600 Subject: [dba-SQLServer] Series of Sundays in a query In-Reply-To: <8786a4c00812091556p67d49abekb8d9d25194562019@mail.gmail.com> References: <39cb22f30812091456j3742829aqff524caedaa810bd@mail.gmail.com> <8786a4c00812091556p67d49abekb8d9d25194562019@mail.gmail.com> Message-ID: <39cb22f30812091703u7423058di5b5f13fe0d2b134@mail.gmail.com> David, Excellent! I'd thought of possibly making a UDF; just never followed through, but that makes perfect sense. Thank you. Steve Erbach On Tue, Dec 9, 2008 at 5:56 PM, David McAfee wrote: > I don't know if is any better, but you can create a udf such as: > > CREATE FUNCTION udfWeekBegins (@StartDate AS DATETIME, @NumOfWks AS > INT) RETURNS @ListTable TABLE (WeekBeginning DATETIME) AS > BEGIN > DECLARE @LoopDate AS DATETIME SET @LoopDate = @StartDate > WHILE @LoopDate < DATEADD(wk, at NumOfWks, at StartDate) > BEGIN > INSERT INTO @ListTable(WeekBeginning) SELECT @LoopDate > SET @LoopDate = DATEADD(dd,7, at LoopDate) > END > RETURN > END > > > > Then call it as such: > SELECT WeekBeginning FROM dbo.udfWeekBegins('12/08/2008',13) --This > returns the next 13 weeks from the date entered, not the next 13 > Sundays > > or like this: > DECLARE @StartWeek AS DATETIME SET @StartWeek = DATEADD(day, 8 - > DATEPART(weekday, GETDATE()), GETDATE()) > SELECT * FROM dbo.udfWeekBegins ( @StartWeek, 13) > > ResultSet: > 2008-12-14 15:55:06.943 > 2008-12-21 15:55:06.943 > 2008-12-28 15:55:06.943 > 2009-01-04 15:55:06.943 > 2009-01-11 15:55:06.943 > 2009-01-18 15:55:06.943 > 2009-01-25 15:55:06.943 > 2009-02-01 15:55:06.943 > 2009-02-08 15:55:06.943 > 2009-02-15 15:55:06.943 > 2009-02-22 15:55:06.943 > 2009-03-01 15:55:06.943 > 2009-03-08 15:55:06.943 > > > > > On Tue, Dec 9, 2008 at 2:56 PM, Steve Erbach wrote: >> >> Dear Group, >> >> In an ASP.NET application I'm writing for work, I'd like to create a >> work scheduling web form. One section contains a check box list of all >> employees, another is a radio button list of the different possible >> shifts to choose from, and a third is a checkbox list of "week >> beginning" dates. The Supervisor checks off all the employees for a >> particular shift, selects the shift, and then selects the weeks that >> those shifts apply. From erbachs at gmail.com Tue Dec 9 19:05:05 2008 From: erbachs at gmail.com (Steve Erbach) Date: Tue, 9 Dec 2008 19:05:05 -0600 Subject: [dba-SQLServer] Series of Sundays in a query In-Reply-To: <000001c95a5b$4a4d3f30$2301a8c0@AB> References: <39cb22f30812091456j3742829aqff524caedaa810bd@mail.gmail.com> <000001c95a5b$4a4d3f30$2301a8c0@AB> Message-ID: <39cb22f30812091705j60afc484jf182213fff6f4312@mail.gmail.com> Asger, I like that solution, too! A table variable is very elegant. Thank you very much! Steve Erbach On Tue, Dec 9, 2008 at 6:07 PM, Asger Blond wrote: > You could use a table variable and a loop like this: > > DECLARE @WeekBeginning datetime > DECLARE @i int > DECLARE @t table(WeekBeginning char(10)) > SET @i=1 > WHILE @i < 91 > BEGIN > SET @i = @i + 7 > INSERT @t VALUES (CONVERT(char(10),GETDATE() + @i,101)) > END > SELECT WeekBeginning FROM @t > > > HTH > Asger > > > > -----Oprindelig meddelelse----- > Fra: dba-sqlserver-bounces at databaseadvisors.com > [mailto:dba-sqlserver-bounces at databaseadvisors.com] P? vegne af Steve Erbach > Sendt: 9. december 2008 23:57 > Til: Discussion concerning MS SQL Server > Emne: [dba-SQLServer] Series of Sundays in a query > > Dear Group, > > In an ASP.NET application I'm writing for work, I'd like to create a > work scheduling web form. One section contains a check box list of all > employees, another is a radio button list of the different possible > shifts to choose from, and a third is a checkbox list of "week > beginning" dates. The Supervisor checks off all the employees for a > particular shift, selects the shift, and then selects the weeks that > those shifts apply. > > Anyway, I want to display 13 weeks of "week beginning dates like so: > > _ 12/14/2008 > _ 12/21/2008 > _ 12/28/2008 > _ 1/4/2009 > etc. From stuart at lexacorp.com.pg Tue Dec 9 19:40:44 2008 From: stuart at lexacorp.com.pg (Stuart McLachlan) Date: Wed, 10 Dec 2008 11:40:44 +1000 Subject: [dba-SQLServer] Series of Sundays in a query In-Reply-To: <39cb22f30812091456j3742829aqff524caedaa810bd@mail.gmail.com> References: <39cb22f30812091456j3742829aqff524caedaa810bd@mail.gmail.com> Message-ID: <493F1E1C.2422.B258121@stuart.lexacorp.com.pg> Best way for this sort of thing is to use a Numbers or Tally Table. If you don't already have one, create it on the fly: -- Drop temporary Numbers table if it exists If object_ID('#Numbers') is not null drop table #Numbers -- Create temporary numbers table with required number of entries select top 13 identity(Int,1,1) as N into #Numbers from master.dbo.syscolumns -- Create list or WeekBeginnings select DATEADD(day, (N * 7 + 1) - DATEPART(weekday, GETDATE()), GETDATE()) AS WeekBeginning from #Numbers -- Drop temporary numbers table drop table #Numbers On 9 Dec 2008 at 16:56, Steve Erbach wrote: > Dear Group, > > In an ASP.NET application I'm writing for work, I'd like to create a > work scheduling web form. One section contains a check box list of all > employees, another is a radio button list of the different possible > shifts to choose from, and a third is a checkbox list of "week > beginning" dates. The Supervisor checks off all the employees for a > particular shift, selects the shift, and then selects the weeks that > those shifts apply. > > Anyway, I want to display 13 weeks of "week beginning dates like so: > > _ 12/14/2008 > _ 12/21/2008 > _ 12/28/2008 > _ 1/4/2009 > etc. > > I have a table in which each row represents the starting date of each > week for the coming year, but I thought that there might be a SQL > query that I could create to generate 13-weeks' worth of > week-beginning dates, starting with the Sunday immediately coming up. > > I searched through Joe Celko's "SQL for Smarties", reading the chapter > on temporal data in SQL, but I didn't see anything suitable. > > Any ideas? The brute force approach is a 13-query UNION something like this: > > SELECT DATEADD(day, 8 - DATEPART(weekday, GETDATE()), GETDATE()) AS > WeekBeginning > UNION > SELECT DATEADD(day, 15 - DATEPART(weekday, GETDATE()), GETDATE()) AS > WeekBeginning > UNION > SELECT DATEADD(day, 22 - DATEPART(weekday, GETDATE()), GETDATE()) AS > WeekBeginning > UNION > etc. > > ...but this seems TOO brute-forcish. > > Regards, > > Steve Erbach > Neenah, WI > http://www.TheTownCrank.com > _______________________________________________ > dba-SQLServer mailing list > dba-SQLServer at databaseadvisors.com > http://databaseadvisors.com/mailman/listinfo/dba-sqlserver > http://www.databaseadvisors.com > From davidmcafee at gmail.com Tue Dec 9 19:59:03 2008 From: davidmcafee at gmail.com (David McAfee) Date: Tue, 9 Dec 2008 17:59:03 -0800 Subject: [dba-SQLServer] Series of Sundays in a query In-Reply-To: <39cb22f30812091703u7423058di5b5f13fe0d2b134@mail.gmail.com> References: <39cb22f30812091456j3742829aqff524caedaa810bd@mail.gmail.com> <8786a4c00812091556p67d49abekb8d9d25194562019@mail.gmail.com> <39cb22f30812091703u7423058di5b5f13fe0d2b134@mail.gmail.com> Message-ID: <8786a4c00812091759o441f3d26wecd45b52aa089390@mail.gmail.com> You're welcome. I decided on having the number of weeks as a parameter that way if you need to call it for a different length you can reuse the same udf. On Tue, Dec 9, 2008 at 5:03 PM, Steve Erbach wrote: > David, > > Excellent! I'd thought of possibly making a UDF; just never followed > through, but that makes perfect sense. Thank you. > > Steve Erbach > > On Tue, Dec 9, 2008 at 5:56 PM, David McAfee wrote: >> I don't know if is any better, but you can create a udf such as: >> >> CREATE FUNCTION udfWeekBegins (@StartDate AS DATETIME, @NumOfWks AS >> INT) RETURNS @ListTable TABLE (WeekBeginning DATETIME) AS >> BEGIN >> DECLARE @LoopDate AS DATETIME SET @LoopDate = @StartDate >> WHILE @LoopDate < DATEADD(wk, at NumOfWks, at StartDate) >> BEGIN >> INSERT INTO @ListTable(WeekBeginning) SELECT @LoopDate >> SET @LoopDate = DATEADD(dd,7, at LoopDate) >> END >> RETURN >> END >> >> >> >> Then call it as such: >> SELECT WeekBeginning FROM dbo.udfWeekBegins('12/08/2008',13) --This >> returns the next 13 weeks from the date entered, not the next 13 >> Sundays >> >> or like this: >> DECLARE @StartWeek AS DATETIME SET @StartWeek = DATEADD(day, 8 - >> DATEPART(weekday, GETDATE()), GETDATE()) >> SELECT * FROM dbo.udfWeekBegins ( @StartWeek, 13) >> >> ResultSet: >> 2008-12-14 15:55:06.943 >> 2008-12-21 15:55:06.943 >> 2008-12-28 15:55:06.943 >> 2009-01-04 15:55:06.943 >> 2009-01-11 15:55:06.943 >> 2009-01-18 15:55:06.943 >> 2009-01-25 15:55:06.943 >> 2009-02-01 15:55:06.943 >> 2009-02-08 15:55:06.943 >> 2009-02-15 15:55:06.943 >> 2009-02-22 15:55:06.943 >> 2009-03-01 15:55:06.943 >> 2009-03-08 15:55:06.943 >> >> >> >> >> On Tue, Dec 9, 2008 at 2:56 PM, Steve Erbach wrote: >>> >>> Dear Group, >>> >>> In an ASP.NET application I'm writing for work, I'd like to create a >>> work scheduling web form. One section contains a check box list of all >>> employees, another is a radio button list of the different possible >>> shifts to choose from, and a third is a checkbox list of "week >>> beginning" dates. The Supervisor checks off all the employees for a >>> particular shift, selects the shift, and then selects the weeks that >>> those shifts apply. > _______________________________________________ > dba-SQLServer mailing list > dba-SQLServer at databaseadvisors.com > http://databaseadvisors.com/mailman/listinfo/dba-sqlserver > http://www.databaseadvisors.com > > From erbachs at gmail.com Wed Dec 10 09:37:21 2008 From: erbachs at gmail.com (Steve Erbach) Date: Wed, 10 Dec 2008 09:37:21 -0600 Subject: [dba-SQLServer] Series of Sundays in a query In-Reply-To: <8786a4c00812091759o441f3d26wecd45b52aa089390@mail.gmail.com> References: <39cb22f30812091456j3742829aqff524caedaa810bd@mail.gmail.com> <8786a4c00812091556p67d49abekb8d9d25194562019@mail.gmail.com> <39cb22f30812091703u7423058di5b5f13fe0d2b134@mail.gmail.com> <8786a4c00812091759o441f3d26wecd45b52aa089390@mail.gmail.com> Message-ID: <39cb22f30812100737r40b419b4kd5cc2dcfd6d0b0a6@mail.gmail.com> David, Righto. Makes perfect sense. Steve Erbach Neenah, WI On Tue, Dec 9, 2008 at 7:59 PM, David McAfee wrote: > You're welcome. > > I decided on having the number of weeks as a parameter that way if you > need to call it for a different length you can reuse the same udf. > > On Tue, Dec 9, 2008 at 5:03 PM, Steve Erbach wrote: >> David, >> >> Excellent! I'd thought of possibly making a UDF; just never followed >> through, but that makes perfect sense. Thank you. >> >> Steve Erbach >> >> On Tue, Dec 9, 2008 at 5:56 PM, David McAfee wrote: >>> I don't know if is any better, but you can create a udf such as: >>> >>> CREATE FUNCTION udfWeekBegins (@StartDate AS DATETIME, @NumOfWks AS >>> INT) RETURNS @ListTable TABLE (WeekBeginning DATETIME) AS >>> BEGIN >>> DECLARE @LoopDate AS DATETIME SET @LoopDate = @StartDate >>> WHILE @LoopDate < DATEADD(wk, at NumOfWks, at StartDate) >>> BEGIN >>> INSERT INTO @ListTable(WeekBeginning) SELECT @LoopDate >>> SET @LoopDate = DATEADD(dd,7, at LoopDate) >>> END >>> RETURN >>> END From erbachs at gmail.com Wed Dec 10 09:40:32 2008 From: erbachs at gmail.com (Steve Erbach) Date: Wed, 10 Dec 2008 09:40:32 -0600 Subject: [dba-SQLServer] Series of Sundays in a query In-Reply-To: <493F1E1C.2422.B258121@stuart.lexacorp.com.pg> References: <39cb22f30812091456j3742829aqff524caedaa810bd@mail.gmail.com> <493F1E1C.2422.B258121@stuart.lexacorp.com.pg> Message-ID: <39cb22f30812100740l24b8a70cgbd41df8941de5799@mail.gmail.com> Stuart, Boy! I had no idea there'd be so many ways to do this: my brute force UNION query, David's UDF, Asger's loop with a table variable, and your temporary Numbers tale. Thank you very much. This has been MOST educational. Steve Erbach Neenah, WI On Tue, Dec 9, 2008 at 7:40 PM, Stuart McLachlan wrote: > Best way for this sort of thing is to use a Numbers or Tally Table. If you don't already have one, > create it on the fly: > > -- Drop temporary Numbers table if it exists > If object_ID('#Numbers') is not null drop table #Numbers > -- Create temporary numbers table with required number of entries > select top 13 identity(Int,1,1) as N > into #Numbers from master.dbo.syscolumns > -- Create list or WeekBeginnings > select DATEADD(day, (N * 7 + 1) - DATEPART(weekday, GETDATE()), > GETDATE()) AS WeekBeginning from #Numbers > -- Drop temporary numbers table > drop table #Numbers > > > On 9 Dec 2008 at 16:56, Steve Erbach wrote: > >> Dear Group, >> >> In an ASP.NET application I'm writing for work, I'd like to create a >> work scheduling web form. One section contains a check box list of all >> employees, another is a radio button list of the different possible >> shifts to choose from, and a third is a checkbox list of "week >> beginning" dates. The Supervisor checks off all the employees for a >> particular shift, selects the shift, and then selects the weeks that >> those shifts apply. >> >> Anyway, I want to display 13 weeks of "week beginning dates like so: >> >> _ 12/14/2008 >> _ 12/21/2008 >> _ 12/28/2008 >> _ 1/4/2009 >> etc. From erbachs at gmail.com Wed Dec 10 10:25:43 2008 From: erbachs at gmail.com (Steve Erbach) Date: Wed, 10 Dec 2008 10:25:43 -0600 Subject: [dba-SQLServer] Performance of a SP Message-ID: <39cb22f30812100825u2243a6h877c3d80b549984@mail.gmail.com> Dear Group, Last week the company that supplies the SQL Server-based security access system upgraded its software. I have an ASP.NET application that queries that SQL Server to retrieve stats for yet another ASP.NET application, an employee In/Out Board. So there are three apps either feeding the SQL Server with new data (the security access system) or querying it (the In/Out Board app and my monitoring app). Our net admin is an uber geek of the first water and he decided to make the SQL Server into a virtual machine on some big honking piece of hardware he recently installed. (Gawd! He was messing with 130 one Terabyte drives a couple of weeks ago while putting three new servers together.) Anyway, the ASP.NET monitoring app is a kind of heads-up display of: 1) A CSS-based bar graph showing the number of people that have come in or gone out of the building over the past three hours. Each pair of bars represents a 15 minute block of time. 2) A list of the users currently running the In/Out Board application. 3) A list of the special security access entries/exits by people like cleaning staff, HVAC repairmen, etc., in the past 24 hours. 4) A list showing he names of employees that have come in and out in the past 15 minutes. 5) A list of the errors logged by the In/Out Board app in the past 24 hours. My problem is with the 6th feature: 6) A list that pops up showing the names of the people summarized in one of the bars of the bar graph. I click on one of the bars in my 3-hour bar graph to see who went IN or OUT during the selected 15-minute period. Up until the upgrade/virtualization the list would pop up quickly...within a second. The list only stays on-screen until I click another bar or until the Monitor app refreshes the stats every 60 seconds. But now every time I click a bar, I wait about 30 seconds seeing nothing happening and then a dialog box appears with the following message: "Timeout expired. The timeout period elapsed prior to completion of the operation or the server is not responding." The message displays in a try-catch block in the VB 2005 web service code that retrieves the data from the SQL Server. I've gone into SSMS and executed the stored procedure, supplied the three parameters, and watched the query take 40 seconds to return the correct result. The stored procdedure contains an IF test and it branches to one of two SELECT queries. If I copy and paste one of the SELECT queries from the IF test and paste it into a new query, DECLARE and SET the three parameters, the query still runs for about 40 seconds. Here's one of the two queries: DECLARE @TimeSlotStart int, @TimeSlotEnd int, @CurrDate datetime; -- The @TimeSlot variables indicate the window of time to examine for employees -- coming into or going out ofthe building; in this case from 120 minutes ago to -- 135 minutes ago. SET @TimeSlotStart = 120; SET @TimeSlotEnd = 135; SET @CurrDate = CONVERT(datetime, '12/10/2008 9:07 AM'); SELECT p.FirstName + ' ' + p.LastName AS Name, CONVERT(char, e.[TimeStamp], 8) AS [Time], 'In' AS IO, d.Name AS Door, CONVERT(char, DATEADD(n, -(@TimeSlotEnd), @CurrDate), 8) AS [Start] -- AccessEvent has about 1.5 million records in it. It's the complete history of -- every In/Out event at any door in the building in the past 6 years or so. FROM AccessEvent AS e INNER JOIN Personnel AS p ON e.PersonId = p.PersonId INNER JOIN Door AS d ON e.DoorId = d.DoorId WHERE ( -- Here's where we define the range of minutes to query between -- the TimeSlotStart and TimeSlotEnd. (e.[TimeStamp] > DATEADD(n, -(@TimeSlotEnd), @CurrDate)) AND (e.[TimeStamp] <= DATEADD(n, -(@TimeSlotStart), @CurrDate)) AND -- This is a list of the three "areas" that an employee can enter -- the building. (e.AreaId IN (1111497563, 1111497564, 1111497571)) AND -- And, finally, a series of conditions that narrow down the list of -- possible employees based on flags set in the Personnel table. (e.CardNumber > 0) AND (p.State > 0) AND ( LTRIM(RTRIM(p.Info1)) IS NULL OR UPPER(LTRIM(RTRIM(p.Info1))) <> 'NOSHOW' ) AND (p.TimeEntered > CONVERT(datetime, '1/1/1989')) ) ORDER BY e.[TimeStamp]; The Personnel table only has about 340 rows. The Doors table, 11 rows. The result set for this query has never been more than 24 rows; that is, 24 people coming or going within a 15 minute window of time. Again, this is one of a pair of SELECT queries that an IF test in the sproc branches to. The other one is identical except that it shows the employees that have gone OUT of the building in the last 15 minutes. The performance of this sproc was never an issue before the upgrade, and the sproc hasn't changed. I ran an Estimated Execution Plan which showed that the Clustered Index Scan on the AccessEvent primary key takes up the bulk of the time. I DID notice that, as part of the upgrade, the AccessEvent table now has 7 non-clustered indexes in addition to the clustered PK index. The indexes include one for [TimeStamp], another for DoorID, another for AreadID, one for CardNumber, and one for PersonID...so all the pertinent fields that are referenced in the big AccessEvent table are indexed fields. Any ideas what might be causing such a slowdown? I'm sorry for the long question, but I wanted to supply complete info. Regards, Steve Erbach Neenah, WI P.S., I DID just notice that there are TWO non-clustered indexes on the same field: [TimeStamp]. I wonder if that has anything to do with it? From nancy.lytle at gmail.com Wed Dec 10 10:40:45 2008 From: nancy.lytle at gmail.com (Nancy Lytle) Date: Wed, 10 Dec 2008 10:40:45 -0600 Subject: [dba-SQLServer] Performance of a SP In-Reply-To: <39cb22f30812100825u2243a6h877c3d80b549984@mail.gmail.com> References: <39cb22f30812100825u2243a6h877c3d80b549984@mail.gmail.com> Message-ID: What about the memory he has set up for the virtual SQL Server? Nancy Lytle N_Lytle at terpalum.umd.edu EMAILING FOR THE GREATER GOODJoin me> Date: Wed, 10 Dec 2008 10:25:43 -0600> From: erbachs at gmail.com> To: dba-sqlserver at databaseadvisors.com> Subject: [dba-SQLServer] Performance of a SP> > Dear Group,> > Last week the company that supplies the SQL Server-based security> access system upgraded its software. I have an ASP.NET application> that queries that SQL Server to retrieve stats for yet another ASP.NET> application, an employee In/Out Board. So there are three apps either> feeding the SQL Server with new data (the security access system) or> querying it (the In/Out Board app and my monitoring app).> > Our net admin is an uber geek of the first water and he decided to> make the SQL Server into a virtual machine on some big honking piece> of hardware he recently installed. (Gawd! He was messing with 130> one Terabyte drives a couple of weeks ago while putting three new> servers together.)> > Anyway, the ASP.NET monitoring app is a kind of heads-up display of:> > 1) A CSS-based bar graph showing the number of people that have come> in or gone out of the building over the past three hours. Each pair> of bars represents a 15 minute block of time.> 2) A list of the users currently running the In/Out Board application.> 3) A list of the special security access entries/exits by people like> cleaning staff, HVAC repairmen, etc., in the past 24 hours.> 4) A list showing he names of employees that have come in and out in> the past 15 minutes.> 5) A list of the errors logged by the In/Out Board app in the past 24 hours.> > My problem is with the 6th feature:> > 6) A list that pops up showing the names of the people summarized in> one of the bars of the bar graph. I click on one of the bars in my> 3-hour bar graph to see who went IN or OUT during the selected> 15-minute period.> > Up until the upgrade/virtualization the list would pop up> quickly...within a second. The list only stays on-screen until I> click another bar or until the Monitor app refreshes the stats every> 60 seconds.> > But now every time I click a bar, I wait about 30 seconds seeing> nothing happening and then a dialog box appears with the following> message:> > "Timeout expired. The timeout period elapsed prior to completion of> the operation or the server is not responding."> > The message displays in a try-catch block in the VB 2005 web service> code that retrieves the data from the SQL Server.> > I've gone into SSMS and executed the stored procedure, supplied the> three parameters, and watched the query take 40 seconds to return the> correct result. The stored procdedure contains an IF test and it> branches to one of two SELECT queries. If I copy and paste one of the> SELECT queries from the IF test and paste it into a new query, DECLARE> and SET the three parameters, the query still runs for about 40> seconds.> > Here's one of the two queries:> > DECLARE> @TimeSlotStart int,> @TimeSlotEnd int,> @CurrDate datetime;> > -- The @TimeSlot variables indicate the window of time to examine for employees> -- coming into or going out ofthe building; in this case from 120 minutes ago to> -- 135 minutes ago.> SET @TimeSlotStart = 120;> SET @TimeSlotEnd = 135;> SET @CurrDate = CONVERT(datetime, '12/10/2008 9:07 AM');> > SELECT> p.FirstName + ' ' + p.LastName AS Name,> CONVERT(char, e.[TimeStamp], 8) AS [Time],> 'In' AS IO,> d.Name AS Door,> CONVERT(char, DATEADD(n, -(@TimeSlotEnd), @CurrDate), 8) AS [Start]> > -- AccessEvent has about 1.5 million records in it. It's the complete> history of> -- every In/Out event at any door in the building in the past 6 years or so.> FROM AccessEvent AS e> INNER JOIN Personnel AS p> ON e.PersonId = p.PersonId> INNER JOIN Door AS d> ON e.DoorId = d.DoorId> WHERE> (> -- Here's where we define the range of minutes to query between> -- the TimeSlotStart and TimeSlotEnd.> (e.[TimeStamp] > DATEADD(n, -(@TimeSlotEnd), @CurrDate)) AND> (e.[TimeStamp] <= DATEADD(n, -(@TimeSlotStart), @CurrDate)) AND> > -- This is a list of the three "areas" that an employee can enter> -- the building.> (e.AreaId IN (1111497563, 1111497564, 1111497571)) AND> > -- And, finally, a series of conditions that narrow down the list of> -- possible employees based on flags set in the Personnel table.> (e.CardNumber > 0) AND> (p.State > 0) AND> (> LTRIM(RTRIM(p.Info1)) IS NULL OR> UPPER(LTRIM(RTRIM(p.Info1))) <> 'NOSHOW'> ) AND> (p.TimeEntered > CONVERT(datetime, '1/1/1989'))> )> ORDER BY e.[TimeStamp];> > The Personnel table only has about 340 rows. The Doors table, 11> rows. The result set for this query has never been more than 24 rows;> that is, 24 people coming or going within a 15 minute window of time.> > Again, this is one of a pair of SELECT queries that an IF test in the> sproc branches to. The other one is identical except that it shows> the employees that have gone OUT of the building in the last 15> minutes.> > The performance of this sproc was never an issue before the upgrade,> and the sproc hasn't changed. I ran an Estimated Execution Plan which> showed that the Clustered Index Scan on the AccessEvent primary key> takes up the bulk of the time.> > I DID notice that, as part of the upgrade, the AccessEvent table now> has 7 non-clustered indexes in addition to the clustered PK index.> The indexes include one for [TimeStamp], another for DoorID, another> for AreadID, one for CardNumber, and one for PersonID...so all the> pertinent fields that are referenced in the big AccessEvent table are> indexed fields.> > Any ideas what might be causing such a slowdown? I'm sorry for the> long question, but I wanted to supply complete info.> > Regards,> > Steve Erbach> Neenah, WI> > P.S., I DID just notice that there are TWO non-clustered indexes on> the same field: [TimeStamp]. I wonder if that has anything to do with> it?> _______________________________________________> dba-SQLServer mailing list> dba-SQLServer at databaseadvisors.com> http://databaseadvisors.com/mailman/listinfo/dba-sqlserver> http://www.databaseadvisors.com> From fhtapia at gmail.com Thu Dec 11 08:08:54 2008 From: fhtapia at gmail.com (Francisco Tapia) Date: Thu, 11 Dec 2008 06:08:54 -0800 Subject: [dba-SQLServer] Performance of a SP In-Reply-To: <39cb22f30812100825u2243a6h877c3d80b549984@mail.gmail.com> References: <39cb22f30812100825u2243a6h877c3d80b549984@mail.gmail.com> Message-ID: Steve, I am a big fan of VM's but even I will admit that there are limitations. SQL requires fast I/o access. So even though the host is a honking machine, how much CPU/ memory is alocated to you SQL vm? Are there any other vm's on the same disk with your VM? Because of the way VM's work, what VM technology did he implement? By that I ask who is the host? Is it esx or is it windows. Sent from my mobile On Dec 10, 2008, at 8:25 AM, "Steve Erbach" wrote: > Dear Group, > > Last week the company that supplies the SQL Server-based security > access system upgraded its software. I have an ASP.NET application > that queries that SQL Server to retrieve stats for yet another ASP.NET > application, an employee In/Out Board. So there are three apps either > feeding the SQL Server with new data (the security access system) or > querying it (the In/Out Board app and my monitoring app). > > Our net admin is an uber geek of the first water and he decided to > make the SQL Server into a virtual machine on some big honking piece > of hardware he recently installed. (Gawd! He was messing with 130 > one Terabyte drives a couple of weeks ago while putting three new > servers together.) > > Anyway, the ASP.NET monitoring app is a kind of heads-up display of: > > 1) A CSS-based bar graph showing the number of people that have come > in or gone out of the building over the past three hours. Each pair > of bars represents a 15 minute block of time. > 2) A list of the users currently running the In/Out Board application. > 3) A list of the special security access entries/exits by people like > cleaning staff, HVAC repairmen, etc., in the past 24 hours. > 4) A list showing he names of employees that have come in and out in > the past 15 minutes. > 5) A list of the errors logged by the In/Out Board app in the past > 24 hours. > > My problem is with the 6th feature: > > 6) A list that pops up showing the names of the people summarized in > one of the bars of the bar graph. I click on one of the bars in my > 3-hour bar graph to see who went IN or OUT during the selected > 15-minute period. > > Up until the upgrade/virtualization the list would pop up > quickly...within a second. The list only stays on-screen until I > click another bar or until the Monitor app refreshes the stats every > 60 seconds. > > But now every time I click a bar, I wait about 30 seconds seeing > nothing happening and then a dialog box appears with the following > message: > > "Timeout expired. The timeout period elapsed prior to completion of > the operation or the server is not responding." > > The message displays in a try-catch block in the VB 2005 web service > code that retrieves the data from the SQL Server. > > I've gone into SSMS and executed the stored procedure, supplied the > three parameters, and watched the query take 40 seconds to return the > correct result. The stored procdedure contains an IF test and it > branches to one of two SELECT queries. If I copy and paste one of the > SELECT queries from the IF test and paste it into a new query, DECLARE > and SET the three parameters, the query still runs for about 40 > seconds. > > Here's one of the two queries: > > DECLARE > @TimeSlotStart int, > @TimeSlotEnd int, > @CurrDate datetime; > > -- The @TimeSlot variables indicate the window of time to examine > for employees > -- coming into or going out ofthe building; in this case from 120 > minutes ago to > -- 135 minutes ago. > SET @TimeSlotStart = 120; > SET @TimeSlotEnd = 135; > SET @CurrDate = CONVERT(datetime, '12/10/2008 9:07 AM'); > > SELECT > p.FirstName + ' ' + p.LastName AS Name, > CONVERT(char, e.[TimeStamp], 8) AS [Time], > 'In' AS IO, > d.Name AS Door, > CONVERT(char, DATEADD(n, -(@TimeSlotEnd), @CurrDate), 8) AS [Start] > > -- AccessEvent has about 1.5 million records in it. It's the complete > history of > -- every In/Out event at any door in the building in the past 6 > years or so. > FROM AccessEvent AS e > INNER JOIN Personnel AS p > ON e.PersonId = p.PersonId > INNER JOIN Door AS d > ON e.DoorId = d.DoorId > WHERE > ( > -- Here's where we define the range of minutes to query between > -- the TimeSlotStart and TimeSlotEnd. > (e.[TimeStamp] > DATEADD(n, -(@TimeSlotEnd), @CurrDate)) AND > (e.[TimeStamp] <= DATEADD(n, -(@TimeSlotStart), @CurrDate)) AND > > -- This is a list of the three "areas" that an employee can enter > -- the building. > (e.AreaId IN (1111497563, 1111497564, 1111497571)) AND > > -- And, finally, a series of conditions that narrow down the list > of > -- possible employees based on flags set in the Personnel table. > (e.CardNumber > 0) AND > (p.State > 0) AND > ( > LTRIM(RTRIM(p.Info1)) IS NULL OR > UPPER(LTRIM(RTRIM(p.Info1))) <> 'NOSHOW' > ) AND > (p.TimeEntered > CONVERT(datetime, '1/1/1989')) > ) > ORDER BY e.[TimeStamp]; > > The Personnel table only has about 340 rows. The Doors table, 11 > rows. The result set for this query has never been more than 24 rows; > that is, 24 people coming or going within a 15 minute window of time. > > Again, this is one of a pair of SELECT queries that an IF test in the > sproc branches to. The other one is identical except that it shows > the employees that have gone OUT of the building in the last 15 > minutes. > > The performance of this sproc was never an issue before the upgrade, > and the sproc hasn't changed. I ran an Estimated Execution Plan which > showed that the Clustered Index Scan on the AccessEvent primary key > takes up the bulk of the time. > > I DID notice that, as part of the upgrade, the AccessEvent table now > has 7 non-clustered indexes in addition to the clustered PK index. > The indexes include one for [TimeStamp], another for DoorID, another > for AreadID, one for CardNumber, and one for PersonID...so all the > pertinent fields that are referenced in the big AccessEvent table are > indexed fields. > > Any ideas what might be causing such a slowdown? I'm sorry for the > long question, but I wanted to supply complete info. > > Regards, > > Steve Erbach > Neenah, WI > > P.S., I DID just notice that there are TWO non-clustered indexes on > the same field: [TimeStamp]. I wonder if that has anything to do with > it? > _______________________________________________ > dba-SQLServer mailing list > dba-SQLServer at databaseadvisors.com > http://databaseadvisors.com/mailman/listinfo/dba-sqlserver > http://www.databaseadvisors.com > From dwaters at usinternet.com Thu Dec 11 11:56:05 2008 From: dwaters at usinternet.com (Dan Waters) Date: Thu, 11 Dec 2008 11:56:05 -0600 Subject: [dba-SQLServer] For Performance - Leave Connection Open? Message-ID: <0670BD77A5944E4D8709BEBD65D9E003@danwaters> In access, I can open and leave open a connection to the BE to noticeably improve performance. I'm starting to use SQL Server as a BE (Access mdb as FE), and one of my clients will be connecting to a BE on a server in the US while they use a FE in Asia. So, should I have the same practice in this system? In this particular case, there will be a limited number of concurrent users - probably 5 at the most. Thanks! Dan From bheid at sc.rr.com Thu Dec 11 20:38:09 2008 From: bheid at sc.rr.com (Bobby Heid) Date: Thu, 11 Dec 2008 21:38:09 -0500 Subject: [dba-SQLServer] Performance of a SP In-Reply-To: References: <39cb22f30812100825u2243a6h877c3d80b549984@mail.gmail.com> Message-ID: <000901c95c02$ac02bb80$04083280$@rr.com> And, if using Hyper-V on Server 2008, check to see if he set up disk pass-through (or something like that). The disk pass-through gives almost the same performance as a native disk out of a VM. Bobby -----Original Message----- From: dba-sqlserver-bounces at databaseadvisors.com [mailto:dba-sqlserver-bounces at databaseadvisors.com] On Behalf Of Francisco Tapia Sent: Thursday, December 11, 2008 9:09 AM To: Discussion concerning MS SQL Server Cc: Discussion concerning MS SQL Server Subject: Re: [dba-SQLServer] Performance of a SP Steve, I am a big fan of VM's but even I will admit that there are limitations. SQL requires fast I/o access. So even though the host is a honking machine, how much CPU/ memory is alocated to you SQL vm? Are there any other vm's on the same disk with your VM? Because of the way VM's work, what VM technology did he implement? By that I ask who is the host? Is it esx or is it windows. Sent from my mobile From dwaters at usinternet.com Fri Dec 19 15:41:50 2008 From: dwaters at usinternet.com (Dan Waters) Date: Fri, 19 Dec 2008 15:41:50 -0600 Subject: [dba-SQLServer] Single User Name for SQL Server Login? Message-ID: <4939D6C517F34F4DAED731A00A11C1EE@danwaters> I was talking to a SQL DBA today at one of my customers. She suggested that I use a single username and password for all of the client PC's (about 200). I'm going to ask her about why we should do this in more detail later. I'm setting up this BE with Windows Authentication. She threw me for a loop - why do this? Is this a standard practice in some situation? My app at this customer has an entire virtual server and the entire SQL instance is for just this app. Thanks! Dan From fuller.artful at gmail.com Sat Dec 20 06:13:24 2008 From: fuller.artful at gmail.com (Arthur Fuller) Date: Sat, 20 Dec 2008 07:13:24 -0500 Subject: [dba-SQLServer] Single User Name for SQL Server Login? In-Reply-To: <4939D6C517F34F4DAED731A00A11C1EE@danwaters> References: <4939D6C517F34F4DAED731A00A11C1EE@danwaters> Message-ID: <29f585dd0812200413k1006867bxb856d0094c8c4a25@mail.gmail.com> In my experience, the most common application of this approach is in apps that involve web UIs. Even then, I don't recommend it because it's impossible to trace an anomoly to a specific user. But in terms of minimal work on the DBA's part, it does make sense. A. On Fri, Dec 19, 2008 at 4:41 PM, Dan Waters wrote: > I was talking to a SQL DBA today at one of my customers. She suggested > that > I use a single username and password for all of the client PC's (about > 200). > I'm going to ask her about why we should do this in more detail later. I'm > setting up this BE with Windows Authentication. > > She threw me for a loop - why do this? Is this a standard practice in some > situation? My app at this customer has an entire virtual server and the > entire SQL instance is for just this app. > > Thanks! > Dan > > _______________________________________________ > dba-SQLServer mailing list > dba-SQLServer at databaseadvisors.com > http://databaseadvisors.com/mailman/listinfo/dba-sqlserver > http://www.databaseadvisors.com > > From dwaters at usinternet.com Sat Dec 20 09:20:14 2008 From: dwaters at usinternet.com (Dan Waters) Date: Sat, 20 Dec 2008 09:20:14 -0600 Subject: [dba-SQLServer] Single User Name for SQL Server Login? In-Reply-To: <29f585dd0812200413k1006867bxb856d0094c8c4a25@mail.gmail.com> References: <4939D6C517F34F4DAED731A00A11C1EE@danwaters> <29f585dd0812200413k1006867bxb856d0094c8c4a25@mail.gmail.com> Message-ID: Thanks Arthur, In fact, we are having login problems with some users, and the login failure report identified specifically who was having a problem. I need separate users. And 'minimal work on the DBA's part' helps me understand. ;-) Dan -----Original Message----- Subject: Re: [dba-SQLServer] Single User Name for SQL Server Login? In my experience, the most common application of this approach is in apps that involve web UIs. Even then, I don't recommend it because it's impossible to trace an anomoly to a specific user. But in terms of minimal work on the DBA's part, it does make sense. A. On Fri, Dec 19, 2008 at 4:41 PM, Dan Waters wrote: > I was talking to a SQL DBA today at one of my customers. She suggested > that > I use a single username and password for all of the client PC's (about > 200). > I'm going to ask her about why we should do this in more detail later. I'm > setting up this BE with Windows Authentication. > > She threw me for a loop - why do this? Is this a standard practice in some > situation? My app at this customer has an entire virtual server and the > entire SQL instance is for just this app. > > Thanks! > Dan From newsgrps at dalyn.co.nz Sun Dec 21 20:30:28 2008 From: newsgrps at dalyn.co.nz (David Emerson) Date: Mon, 22 Dec 2008 15:30:28 +1300 Subject: [dba-SQLServer] XP adp and SQL2005 Message-ID: <20081222023004.UUTA28627.mta02.xtra.co.nz@Dalyn.dalyn.co.nz> I have a view being used for a subform. It combines 4 tables but only one has data which is changed. It is a 'many' table. All of the tables have primary keys. The table being edited has a timestamp column created when the database was upsized from Access XP to SQL2000. The database was then scripted and created on SQL2005. When I try to add a record I get the following error: Cannot insert an explicit value into a timestamp column. Use INSERT with a column list to exclude the timestamp column, or insert a DEFAULT. Because I am using a bound form I do not have the option of a column list (I don't think). If I remove the timestamp field from the view then I don't even get an option to add a record. With the timestamp included I can add the data for a new record, but just can't save it. I am not sure what is meant in the error message by "Insert a default". I tried adding a textbox to the form for the timestamp field and put DEFAULT in the default property but this didn't work. Does anyone have any suggestions? Regards David Emerson Dalyn Software Ltd Wellington, New Zealand From markamatte at hotmail.com Mon Dec 22 09:12:25 2008 From: markamatte at hotmail.com (Mark A Matte) Date: Mon, 22 Dec 2008 15:12:25 +0000 Subject: [dba-SQLServer] XP adp and SQL2005 In-Reply-To: <20081222023004.UUTA28627.mta02.xtra.co.nz@Dalyn.dalyn.co.nz> References: <20081222023004.UUTA28627.mta02.xtra.co.nz@Dalyn.dalyn.co.nz> Message-ID: Dave, I am by no means an expert with SQL Server...(add a grain of salt here)...but I was able to recreate this...and found this link: http://www.experts-exchange.com/Microsoft/Applications/FoxPro/Q_22012455.html If I understand this...timestamp is just that...a timestamp the system automatically generates and stores(kinda like an autonumber...but for row versioning)...it is not for the user to add. Another link explaining some uses: http://www.sqlusa.com/articles2005/rowversion/ Good luck, Hope this helps... Mark A. Matte > Date: Mon, 22 Dec 2008 15:30:28 +1300 > To: accessd at databaseadvisors.com; dba-SQLServer at databaseadvisors.com > From: newsgrps at dalyn.co.nz > Subject: [dba-SQLServer] XP adp and SQL2005 > > I have a view being used for a subform. It combines 4 tables but > only one has data which is changed. It is a 'many' table. All of > the tables have primary keys. > > The table being edited has a timestamp column created when the > database was upsized from Access XP to SQL2000. The database was > then scripted and created on SQL2005. > > When I try to add a record I get the following error: > > Cannot insert an explicit value into a timestamp column. Use INSERT > with a column list to exclude the timestamp column, or insert a DEFAULT. > > Because I am using a bound form I do not have the option of a column > list (I don't think). If I remove the timestamp field from the view > then I don't even get an option to add a record. With the timestamp > included I can add the data for a new record, but just can't save it. > > I am not sure what is meant in the error message by "Insert a > default". I tried adding a textbox to the form for the timestamp > field and put DEFAULT in the default property but this didn't work. > > Does anyone have any suggestions? > > Regards > > David Emerson > Dalyn Software Ltd > Wellington, New Zealand > > _______________________________________________ > dba-SQLServer mailing list > dba-SQLServer at databaseadvisors.com > http://databaseadvisors.com/mailman/listinfo/dba-sqlserver > http://www.databaseadvisors.com > 3 _________________________________________________________________ Send e-mail faster without improving your typing skills. http://windowslive.com/online/hotmail?ocid=TXT_TAGLM_WL_hotmail_acq_speed_122008 From newsgrps at dalyn.co.nz Mon Dec 22 12:41:27 2008 From: newsgrps at dalyn.co.nz (David Emerson) Date: Tue, 23 Dec 2008 07:41:27 +1300 Subject: [dba-SQLServer] XP adp and SQL2005 In-Reply-To: References: <20081222023004.UUTA28627.mta02.xtra.co.nz@Dalyn.dalyn.co.nz> Message-ID: <20081222184111.WHBZ28627.mta02.xtra.co.nz@Dalyn.dalyn.co.nz> Thanks Mark, While it didn't solve my problem, it pointed me to another solution base. I am taking advantage of their free subscription to see if they have any answers. Regards David At 23/12/2008, you wrote: >Dave, > >I am by no means an expert with SQL Server...(add a grain of salt >here)...but I was able to recreate this...and found this link: > >http://www.experts-exchange.com/Microsoft/Applications/FoxPro/Q_22012455.html > >If I understand this...timestamp is just that...a timestamp the >system automatically generates and stores(kinda like an >autonumber...but for row versioning)...it is not for the user to add. > >Another link explaining some uses: >http://www.sqlusa.com/articles2005/rowversion/ > >Good luck, > >Hope this helps... > >Mark A. Matte > > > > > > > Date: Mon, 22 Dec 2008 15:30:28 +1300 > > To: accessd at databaseadvisors.com; dba-SQLServer at databaseadvisors.com > > From: newsgrps at dalyn.co.nz > > Subject: [dba-SQLServer] XP adp and SQL2005 > > > > I have a view being used for a subform. It combines 4 tables but > > only one has data which is changed. It is a 'many' table. All of > > the tables have primary keys. > > > > The table being edited has a timestamp column created when the > > database was upsized from Access XP to SQL2000. The database was > > then scripted and created on SQL2005. > > > > When I try to add a record I get the following error: > > > > Cannot insert an explicit value into a timestamp column. Use INSERT > > with a column list to exclude the timestamp column, or insert a DEFAULT. > > > > Because I am using a bound form I do not have the option of a column > > list (I don't think). If I remove the timestamp field from the view > > then I don't even get an option to add a record. With the timestamp > > included I can add the data for a new record, but just can't save it. > > > > I am not sure what is meant in the error message by "Insert a > > default". I tried adding a textbox to the form for the timestamp > > field and put DEFAULT in the default property but this didn't work. > > > > Does anyone have any suggestions? > > > > Regards > > > > David Emerson > > Dalyn Software Ltd > > Wellington, New Zealand > > > > _______________________________________________ > > dba-SQLServer mailing list > > dba-SQLServer at databaseadvisors.com > > http://databaseadvisors.com/mailman/listinfo/dba-sqlserver > > http://www.databaseadvisors.com > > 3 >_________________________________________________________________ >Send e-mail faster without improving your typing skills. >http://windowslive.com/online/hotmail?ocid=TXT_TAGLM_WL_hotmail_acq_speed_122008 >_______________________________________________ >dba-SQLServer mailing list >dba-SQLServer at databaseadvisors.com >http://databaseadvisors.com/mailman/listinfo/dba-sqlserver >http://www.databaseadvisors.com From john at winhaven.net Mon Dec 22 23:38:24 2008 From: john at winhaven.net (John Bartow) Date: Mon, 22 Dec 2008 23:38:24 -0600 Subject: [dba-SQLServer] Happy Hanukkah Message-ID: <008e01c964c0$ac552750$04ff75f0$@net> A Happy Hanukkah from the Database Advisors Board of Directors. Here's a little JibJab fun: http://www.winhaven.net/misc/HappyHanukkahDBA.html From fuller.artful at gmail.com Tue Dec 23 04:11:04 2008 From: fuller.artful at gmail.com (Arthur Fuller) Date: Tue, 23 Dec 2008 05:11:04 -0500 Subject: [dba-SQLServer] Gmai is acting funny Message-ID: <29f585dd0812230211h1af7fb93s21c879706e46e3d4@mail.gmail.com> i have noticed lately that not everything I send shows up in the Sent Mail folder. And yet I get replies to these. Any idea what's going on? Happy holiday season everyone, Arthur From john at winhaven.net Wed Dec 24 12:00:25 2008 From: john at winhaven.net (John Bartow) Date: Wed, 24 Dec 2008 12:00:25 -0600 Subject: [dba-SQLServer] Merry Christmas - Its a Wonderful Life Message-ID: <000e01c965f1$7f6ea090$7e4be1b0$@net> Merry Christmas Hanukkah from the Database Advisors Board of Directors. If you've seen "It's a Wonderful Life", here's a little JibJab Christmas fun: (Some of the BoD didn't make the Hanukkah greeting so here's the rest in "It's a Wonderful Life") http://www.winhaven.net/misc/DBAItsaWonderfulLife.htm John B. PS: Parts were limited so I had to do what I had to do ;o) From garykjos at gmail.com Wed Dec 24 12:11:16 2008 From: garykjos at gmail.com (Gary Kjos) Date: Wed, 24 Dec 2008 12:11:16 -0600 Subject: [dba-SQLServer] [dba-OT] Merry Christmas - Its a Wonderful Life In-Reply-To: <000e01c965f1$7f6ea090$7e4be1b0$@net> References: <000e01c965f1$7f6ea090$7e4be1b0$@net> Message-ID: That is great! Merry Christmas! GK On 12/24/08, John Bartow wrote: > Merry Christmas Hanukkah from the Database Advisors Board of Directors. > > If you've seen "It's a Wonderful Life", here's a little JibJab Christmas > fun: > (Some of the BoD didn't make the Hanukkah greeting so here's the rest in > "It's a Wonderful Life") > http://www.winhaven.net/misc/DBAItsaWonderfulLife.htm > > John B. > PS: Parts were limited so I had to do what I had to do ;o) > > _______________________________________________ > dba-OT mailing list > dba-OT at databaseadvisors.com > http://databaseadvisors.com/mailman/listinfo/dba-ot > Website: http://www.databaseadvisors.com > -- Gary Kjos garykjos at gmail.com From ridermark at gmail.com Wed Dec 24 22:16:39 2008 From: ridermark at gmail.com (Mark Rider) Date: Wed, 24 Dec 2008 22:16:39 -0600 Subject: [dba-SQLServer] [dba-VB] Merry Christmas - Its a Wonderful Life In-Reply-To: <000e01c965f1$7f6ea090$7e4be1b0$@net> References: <000e01c965f1$7f6ea090$7e4be1b0$@net> Message-ID: Happy Holidays! **(See Footnote 1) ** Footnote 1: Please accept with no obligation, implied or implicit, our best wishes for an environmentally conscious, socially responsible, low stress, non-addictive, gender neutral, celebration of the winter solstice holiday, practiced within the most enjoyable traditions of the religious persuasion of your choice, or secular practices of your choice, with respect for the religious/secular persuasions and/or traditions of others, or their choice not to practice religious or secular traditions at all . . . and a fiscally successful, personally fulfilling, and medically uncomplicated recognition of the onset of the generally accepted calendar year 2009, but not without due respect for the calendars of choice of other cultures whose contributions to society have helped make America great, (not to imply that America is necessarily greater than any other country or is the only "AMERICA" in the western hemisphere), and without regard to the race, creed, color, age, physical ability, religious faith, choice of computer platform, or sexual preference of the wishee. By accepting this greeting, you are accepting these terms. This greeting is subject to clarification or withdrawal. It is freely transferable with no alteration to the original greeting. It implies no promise by the wisher to actually implement any of the wishes for her/himself or others, and is void where prohibited by law, and is revocable at the sole discretion of the wisher. This wish is warranted to perform as expected within the usual application of good tidings for a period of one year, or until the issuance of a subsequent holiday greeting, whichever comes first, and warranty is limited to replacement of this wish or issuance of a new wish at the sole discretion of the wisher. The wishee further agrees to hold harmless and indemnify the wisher, along with its heirs, assigns, officers, directors, shareholders . . . -- Mark Rider http://commonsensesecurity.info Try to learn something about everything and everything about something. - Thomas H. Huxley From Robert at webedb.com Mon Dec 29 09:12:06 2008 From: Robert at webedb.com (Robert) Date: Mon, 29 Dec 2008 10:12:06 -0500 Subject: [dba-SQLServer] XP adp and SQL2005 Message-ID: <04a6ee3ea0814511b3b37c9306164c63@webedb.com> Depending on the GUI for this, the ODBC driver uses the Timestamp column to determine if a change has been made. You cannot include the Timestamp column in the insert statement. You need to either rewrite the INSERT or, do not bind the timestamp column when using it in the GUI. So, in your case, do not include the timestamp column in the control on the ADP form. ---------------------------------------- > > Date: Mon, 22 Dec 2008 15:30:28 +1300 > > To: accessd at databaseadvisors.com; dba-SQLServer at databaseadvisors.com > > From: newsgrps at dalyn.co.nz > > Subject: [dba-SQLServer] XP adp and SQL2005 > > > > I have a view being used for a subform. It combines 4 tables but > > only one has data which is changed. It is a 'many' table. All of > > the tables have primary keys. > > > > The table being edited has a timestamp column created when the > > database was upsized from Access XP to SQL2000. The database was > > then scripted and created on SQL2005. > > > > When I try to add a record I get the following error: > > > > Cannot insert an explicit value into a timestamp column. Use INSERT > > with a column list to exclude the timestamp column, or insert a DEFAULT. > > > > Because I am using a bound form I do not have the option of a column > > list (I don't think). If I remove the timestamp field from the view > > then I don't even get an option to add a record. With the timestamp > > included I can add the data for a new record, but just can't save it. > > > > I am not sure what is meant in the error message by "Insert a > > default". I tried adding a textbox to the form for the timestamp > > field and put DEFAULT in the default property but this didn't work. > > > > Does anyone have any suggestions? > > > > Regards > > > > David Emerson > > Dalyn Software Ltd > > Wellington, New Zealand > > > > _______________________________________________ > > dba-SQLServer mailing list > > dba-SQLServer at databaseadvisors.com > > http://databaseadvisors.com/mailman/listinfo/dba-sqlserver > > http://www.databaseadvisors.com > > 3 >_________________________________________________________________ >Send e-mail faster without improving your typing skills. >http://windowslive.com/online/hotmail?ocid=TXT_TAGLM_WL_hotmail_acq_speed_122008 >_______________________________________________ >dba-SQLServer mailing list >dba-SQLServer at databaseadvisors.com >http://databaseadvisors.com/mailman/listinfo/dba-sqlserver >http://www.databaseadvisors.com ------------------------------ Message: 2 Date: Mon, 22 Dec 2008 23:38:24 -0600 From: "John Bartow" Subject: [dba-SQLServer] Happy Hanukkah To: , "_DBA-Access" , "_DBA-OT" , "_DBA-Tech" , Message-ID: <008e01c964c0$ac552750$04ff75f0$@net> Content-Type: text/plain; charset="us-ascii" A Happy Hanukkah from the Database Advisors Board of Directors. Here's a little JibJab fun: http://www.winhaven.net/misc/HappyHanukkahDBA.html ------------------------------ Message: 3 Date: Tue, 23 Dec 2008 05:11:04 -0500 From: "Arthur Fuller" Subject: [dba-SQLServer] Gmai is acting funny To: "Discussion concerning MS SQL Server" Message-ID: <29f585dd0812230211h1af7fb93s21c879706e46e3d4 at mail.gmail.com> Content-Type: text/plain; charset=ISO-8859-1 i have noticed lately that not everything I send shows up in the Sent Mail folder. And yet I get replies to these. Any idea what's going on? Happy holiday season everyone, Arthur ------------------------------ _______________________________________________ dba-SQLServer mailing list dba-SQLServer at databaseadvisors.com http://databaseadvisors.com/mailman/listinfo/dba-sqlserver End of dba-SQLServer Digest, Vol 70, Issue 8 ********************************************