SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


What is wrong with this syntax? Query will work, but CTE will not "compile"


What is wrong with this syntax? Query will work, but CTE will not "compile"

Author
Message
Tobar
Tobar
Say Hey Kid
Say Hey Kid (663 reputation)Say Hey Kid (663 reputation)Say Hey Kid (663 reputation)Say Hey Kid (663 reputation)Say Hey Kid (663 reputation)Say Hey Kid (663 reputation)Say Hey Kid (663 reputation)Say Hey Kid (663 reputation)

Group: General Forum Members
Points: 663 Visits: 758
with UnloadDates as   select DISTINCT ShipmentID,
(select Min(starttime)
from tblInvoice I
where I.ShipmentID = O.shipmentID
and DataSent is null
) StartTime,
(select Max(Endtime)
from tblInvoice I
where I.ShipmentID = O.shipmentID
and DataSent is null
) EndTime
from tblInvoice O
where O.startTime IS NOT NULL
and O.EndTime IS NOT NULL
and O.DataSent is null


Msg 156, Level 15, State 1, Line 4
Incorrect syntax near the keyword 'select'.


Appreciate the help

<><
Livin' down on the cube farm. Left, left, then a right.
Andrew Kernodle
Andrew Kernodle
SSC Eights!
SSC Eights! (918 reputation)SSC Eights! (918 reputation)SSC Eights! (918 reputation)SSC Eights! (918 reputation)SSC Eights! (918 reputation)SSC Eights! (918 reputation)SSC Eights! (918 reputation)SSC Eights! (918 reputation)

Group: General Forum Members
Points: 918 Visits: 8135
Hrm. Seems like your CTE declaration is missing a few pieces; I believe it should be like so:


with UnloadDates(ShipmentId,StartTime,EndTime) as(
select DISTINCT ShipmentID,
(select Min(starttime)
from tblInvoice I
where I.ShipmentID = O.shipmentID
and DataSent is null
) StartTime,
(select Max(Endtime)
from tblInvoice I
where I.ShipmentID = O.shipmentID
and DataSent is null
) EndTime
from tblInvoice O
where O.startTime IS NOT NULL
and O.EndTime IS NOT NULL
and O.DataSent is null)



The CTE needs to have a column listing in the format of: CTEName(Column1,Column2,...). After the AS, you need a starting parenthesis, which you close at the end of your CTE query.

Post back if it's still giving you issues; I believe I caught the errors, but there might be something I overlooked.

EDIT: Doh, forgot the closing parenthesis.

- :-D
Eirikur Eiriksson
Eirikur Eiriksson
SSC-Insane
SSC-Insane (21K reputation)SSC-Insane (21K reputation)SSC-Insane (21K reputation)SSC-Insane (21K reputation)SSC-Insane (21K reputation)SSC-Insane (21K reputation)SSC-Insane (21K reputation)SSC-Insane (21K reputation)

Group: General Forum Members
Points: 21615 Visits: 18861
hisakimatama (4/8/2014)

EDIT: Doh, forgot the closing parenthesis.

The parenthesis where the problem, a CTE does not require the columnar declaration.
Cool
Luis Cazares
Luis Cazares
SSC-Insane
SSC-Insane (23K reputation)SSC-Insane (23K reputation)SSC-Insane (23K reputation)SSC-Insane (23K reputation)SSC-Insane (23K reputation)SSC-Insane (23K reputation)SSC-Insane (23K reputation)SSC-Insane (23K reputation)

Group: General Forum Members
Points: 23076 Visits: 19392
Since you're correcting this code, why don't we make it simpler and faster?

WITH UnloadDates AS(
SELECT ShipmentID,
MIN(starttime) StartTime,
MAX(Endtime) EndTime
FROM tblInvoice O
WHERE O.startTime IS NOT NULL
AND O.EndTime IS NOT NULL
AND O.DataSent is null
GROUP BY ShipmentID
)
SELECT ShipmentID,
StartTime,
EndTime
FROM UnloadDates


This way you read the table just once instead of trice. It's also a lot less code. :-)


Luis C.
General Disclaimer:
Are you seriously taking the advice and code from someone from the internet without testing it? Do you at least understand it? Or can it easily kill your server?


How to post data/code on a forum to get the best help: Option 1 / Option 2
Tobar
Tobar
Say Hey Kid
Say Hey Kid (663 reputation)Say Hey Kid (663 reputation)Say Hey Kid (663 reputation)Say Hey Kid (663 reputation)Say Hey Kid (663 reputation)Say Hey Kid (663 reputation)Say Hey Kid (663 reputation)Say Hey Kid (663 reputation)

Group: General Forum Members
Points: 663 Visits: 758
Arrgh. Sorry. I keep thinking those are input parameters, not output.

Another issue I had is that you can not just "compile" (execute) a CTE definition by itself without some follow on expressions. Whistling

<><
Livin' down on the cube farm. Left, left, then a right.
Tobar
Tobar
Say Hey Kid
Say Hey Kid (663 reputation)Say Hey Kid (663 reputation)Say Hey Kid (663 reputation)Say Hey Kid (663 reputation)Say Hey Kid (663 reputation)Say Hey Kid (663 reputation)Say Hey Kid (663 reputation)Say Hey Kid (663 reputation)

Group: General Forum Members
Points: 663 Visits: 758
Luis Cazares (4/8/2014)
Since you're correcting this code, why don't we make it simpler and faster?
This way you read the table just once instead of trice. It's also a lot less code. :-)

Oye. I didn't write it that way because I have a memory, evidently faulty, that that would not work. But it does. And since it does, I might not even need the CTE.

You guys (which includes gals) are the best!!!!

<><
Livin' down on the cube farm. Left, left, then a right.
Grant Fritchey
Grant Fritchey
SSC Guru
SSC Guru (56K reputation)SSC Guru (56K reputation)SSC Guru (56K reputation)SSC Guru (56K reputation)SSC Guru (56K reputation)SSC Guru (56K reputation)SSC Guru (56K reputation)SSC Guru (56K reputation)

Group: General Forum Members
Points: 56599 Visits: 32799
Tobar (4/8/2014)
Arrgh. Sorry. I keep thinking those are input parameters, not output.

Another issue I had is that you can not just "compile" (execute) a CTE definition by itself without some follow on expressions. Whistling


Joke?

If not, that's because a CTE is just a query, a derived table, no different than if you did a SELECT FROM a SELECT FROM. The CTE only exists within the context of it's following statement.

If it was a joke, sorry for getting pedantic.

----------------------------------------------------
The credit belongs to the man who is actually in the arena, whose face is marred by dust and sweat and blood...
Theodore Roosevelt

The Scary DBA
Author of: SQL Server Query Performance Tuning and SQL Server Execution Plans
Product Evangelist for Red Gate Software
Tobar
Tobar
Say Hey Kid
Say Hey Kid (663 reputation)Say Hey Kid (663 reputation)Say Hey Kid (663 reputation)Say Hey Kid (663 reputation)Say Hey Kid (663 reputation)Say Hey Kid (663 reputation)Say Hey Kid (663 reputation)Say Hey Kid (663 reputation)

Group: General Forum Members
Points: 663 Visits: 758
Alas ignorance, possibly just not thinking it through, but most likely ignorance.Blush

<><
Livin' down on the cube farm. Left, left, then a right.
Andrew Kernodle
Andrew Kernodle
SSC Eights!
SSC Eights! (918 reputation)SSC Eights! (918 reputation)SSC Eights! (918 reputation)SSC Eights! (918 reputation)SSC Eights! (918 reputation)SSC Eights! (918 reputation)SSC Eights! (918 reputation)SSC Eights! (918 reputation)

Group: General Forum Members
Points: 918 Visits: 8135
Eirikur Eiriksson (4/8/2014)
hisakimatama (4/8/2014)

EDIT: Doh, forgot the closing parenthesis.

The parenthesis where the problem, a CTE does not require the columnar declaration.
Cool


Aha, so it doesn't :-). I've always declared CTEs with the column declarations, and by the wonderful problems of habit, it stuck as "the" way to do it. Well, I learned something that should make syntax a good bit clearer myself :-D

- :-D
Eirikur Eiriksson
Eirikur Eiriksson
SSC-Insane
SSC-Insane (21K reputation)SSC-Insane (21K reputation)SSC-Insane (21K reputation)SSC-Insane (21K reputation)SSC-Insane (21K reputation)SSC-Insane (21K reputation)SSC-Insane (21K reputation)SSC-Insane (21K reputation)

Group: General Forum Members
Points: 21615 Visits: 18861
hisakimatama (4/8/2014)

Aha, so it doesn't :-). I've always declared CTEs with the column declarations, and by the wonderful problems of habit, it stuck as "the" way to do it. Well, I learned something that should make syntax a good bit clearer myself :-D

I prefer it, makes the code more readable.
Cool
Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum

































































































































































SQLServerCentral


Search