April 27, 2012 at 12:18 pm
Table consists of:
Area|Date|Employee|Qty where Area|date|employee are the key
On "Sunday" someone will complete these for Monday. The probability is that the key fields will remain constant for the next 4 days.
Is it possible that is could filter the key fields where Date = "today", and then copy the records * 4 each time incrementating the date?
I have thought about copying "Today" out to a temp table, dateadd + 1 and then inserting these back into the table. I guess i need to loop, but as am i newbie, a point in the right direction would be appreciated.
I can run these as storedprocedure overnight so when they arrive on Tue, the entries are already in.
Thanks 🙂
April 27, 2012 at 12:25 pm
I seriously doubt you need a loop for this. Take a look at the first link in my signature for best practices on posting questions. After you post ddl, sample data and desired result we can knock this out pretty easily.
_______________________________________________________________
Need help? Help us help you.
Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.
Need to split a string? Try Jeff Modens splitter http://www.sqlservercentral.com/articles/Tally+Table/72993/.
Cross Tabs and Pivots, Part 1 – Converting Rows to Columns - http://www.sqlservercentral.com/articles/T-SQL/63681/
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs - http://www.sqlservercentral.com/articles/Crosstab/65048/
Understanding and Using APPLY (Part 1) - http://www.sqlservercentral.com/articles/APPLY/69953/
Understanding and Using APPLY (Part 2) - http://www.sqlservercentral.com/articles/APPLY/69954/
April 29, 2012 at 4:47 pm
markpc2009 (4/27/2012)
Table consists of:Area|Date|Employee|Qty where Area|date|employee are the key
On "Sunday" someone will complete these for Monday. The probability is that the key fields will remain constant for the next 4 days.
Is it possible that is could filter the key fields where Date = "today", and then copy the records * 4 each time incrementating the date?
I have thought about copying "Today" out to a temp table, dateadd + 1 and then inserting these back into the table. I guess i need to loop, but as am i newbie, a point in the right direction would be appreciated.
I can run these as storedprocedure overnight so when they arrive on Tue, the entries are already in.
Thanks 🙂
It's easy...
INSERT INTO yourtable
(Area, Date, Employee)
SELECT Area, Date = DATEADD(dd.t.N,Date), Employee
FROM yourtable yt
CROSS JOIN (SELECT 1 UNION ALL SELECT 2 UNION ALL SELECT 3 UNION ALL SELECT 4) t (N)
WHERE yt.DATE = DATEDIFF(dd,0,GETDATE())
;
--Jeff Moden
Change is inevitable... Change for the better is not.
April 30, 2012 at 7:06 am
This is the code which i am using, but i am getting incorrect syntax near 4 which is on the cross join line...
INSERT INTO mytable
([Area],[Employee No_],[Date]
SELECT
[Area],[Employee No_],[Date]= DATEADD (dd,4,[Date])
FROM mytable
CROSS JOIN (SELECT 1 UNION ALL SELECT 2 UNION ALL SELECT 3 UNION ALL SELECT 4)[Date] (4)
WHERE [DATE] = DATEDIFF(dd,0,GETDATE())
in your example, what does t mean?
April 30, 2012 at 7:18 am
I have managed to solve the syntax error, by doing:
CROSS JOIN (SELECT 1 UNION ALL SELECT 2 UNION ALL SELECT 3 UNION ALL SELECT 4) as T (N)
and i do now have the additional lines - however these all have the same date.
what should be happening is
today = 30/04/2012
so the additional lines should be
01/05/2012
02/05/2012
etc
April 30, 2012 at 7:36 am
Again if you want detailed help you need to provide ddl, sample data and desired output. This is pretty straight forward code but without something to work we are shooting in the dark. We can get close sometimes like Jeff did above, but not exact.
_______________________________________________________________
Need help? Help us help you.
Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.
Need to split a string? Try Jeff Modens splitter http://www.sqlservercentral.com/articles/Tally+Table/72993/.
Cross Tabs and Pivots, Part 1 – Converting Rows to Columns - http://www.sqlservercentral.com/articles/T-SQL/63681/
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs - http://www.sqlservercentral.com/articles/Crosstab/65048/
Understanding and Using APPLY (Part 1) - http://www.sqlservercentral.com/articles/APPLY/69953/
Understanding and Using APPLY (Part 2) - http://www.sqlservercentral.com/articles/APPLY/69954/
April 30, 2012 at 7:45 am
Try this
INSERT INTO mytable
([Area],[Employee No_],[Date]
SELECT
[Area],[Employee No_],[Date]= DATEADD (dd,N,[Date]) -- Replace the hard coded 4 with "N"
FROM mytable
CROSS JOIN (SELECT 1 UNION ALL SELECT 2 UNION ALL SELECT 3 UNION ALL SELECT 4) AS T (N)
WHERE [DATE] = DATEDIFF(dd,0,GETDATE())
How to post data/code on a forum to get the best help - Jeff Moden
http://www.sqlservercentral.com/articles/Best+Practices/61537/
April 30, 2012 at 7:49 am
markpc2009 (4/30/2012)
This is the code which i am using, but i am getting incorrect syntax near 4 which is on the cross join line...
INSERT INTO mytable
([Area],[Employee No_],[Date]
SELECT
[Area],[Employee No_],[Date]= DATEADD (dd,4,[Date])
FROM mytable
CROSS JOIN (SELECT 1 UNION ALL SELECT 2 UNION ALL SELECT 3 UNION ALL SELECT 4)[Date] (4)
WHERE [DATE] = DATEDIFF(dd,0,GETDATE())
in your example, what does t mean?
t is the alias for the derived table. You'll need that to name the table and you'll also need to put it back in the dateadd calc.
______________________________________________________________________________
How I want a drink, alcoholic of course, after the heavy lectures involving quantum mechanics.
April 30, 2012 at 11:11 am
markpc2009 (4/30/2012)
I have managed to solve the syntax error, by doing:CROSS JOIN (SELECT 1 UNION ALL SELECT 2 UNION ALL SELECT 3 UNION ALL SELECT 4) as T (N)
and i do now have the additional lines - however these all have the same date.
what should be happening is
today = 30/04/2012
so the additional lines should be
01/05/2012
02/05/2012
etc
The code I wrote for you worked just fine. Why are you trying to rewrite it?
--Jeff Moden
Change is inevitable... Change for the better is not.
April 30, 2012 at 12:13 pm
The code I wrote for you worked just fine. Why are you trying to rewrite it?
Actually, there's a typo in the original which probably threw him off.
DATEADD(dd.t.N,Date)
______________________________________________________________________________
How I want a drink, alcoholic of course, after the heavy lectures involving quantum mechanics.
April 30, 2012 at 3:12 pm
Thanks all. Changing the 4 backup N sorted it.
The reason I rewrote was due to getting syntax so I tried to resolve before asking.
I didn't post the original table set up etc was the first solution was exactly what I was after, only I needed help in doing the slight tweak.
Again thanks for your help, and I will be back !
Viewing 11 posts - 1 through 10 (of 10 total)
You must be logged in to reply to this topic. Login to reply