January 16, 2013 at 3:23 pm
Hello,
It seems that DELETE statements don't support aliases. Is that correct in 2k8R2?
Also, the query attached does not permit the alias x. Why and how can I rewrite the query without using the alias x?
Thanks a lot in advance,
Gabor
January 16, 2013 at 4:00 pm
Here is a script demonstrating a delete using an alias as well as using the alias X
Use Tempdb;
GO
CREATE TABLE demodelete (somenum INT);
INSERT INTO demodelete (somenum)
VALUES (1),(2),(3),(4);
SELECT * FROM demodelete;
DELETE X
FROM demodelete x
WHERE x.somenum = 1;
SELECT *
FROM demodelete;
Jason...AKA CirqueDeSQLeil
_______________________________________________
I have given a name to my pain...MCM SQL Server, MVP
SQL RNNR
Posting Performance Based Questions - Gail Shaw[/url]
Learn Extended Events
January 16, 2013 at 6:25 pm
Hello,
Thanks for the response. However, I still have two questions:
1. Why is the X necessary after the DELETE key word? Wouldn't DELETE FROM demodelete x WHERE x.somenum = 1; work? If not, why?
2. What is wrong with the usage of the alias x in the query attached to the original message?
Thanks again!
Gabor
SQLRNNR (1/16/2013)
Here is a script demonstrating a delete using an alias as well as using the alias X
Use Tempdb;
GO
CREATE TABLE demodelete (somenum INT);
INSERT INTO demodelete (somenum)
VALUES (1),(2),(3),(4);
SELECT * FROM demodelete;
DELETE X
FROM demodelete x
WHERE x.somenum = 1;
SELECT *
FROM demodelete;
January 16, 2013 at 8:33 pm
The X isn't necessary. You asked about delete statements not working with aliases. That is merely a demo showing that aliases do in fact work with delete statements.
As for your query, attached as a download document I won't download it. Paste your query into a paste instead of as an attachment (that must be downloaded).
Jason...AKA CirqueDeSQLeil
_______________________________________________
I have given a name to my pain...MCM SQL Server, MVP
SQL RNNR
Posting Performance Based Questions - Gail Shaw[/url]
Learn Extended Events
January 17, 2013 at 9:51 am
grevesz (1/16/2013)
1. Why is the X necessary after the DELETE key word? Wouldn't DELETE FROM demodelete x WHERE x.somenum = 1; work? If not, why?
The DELETE statement consists of six parts:
1) An optional CTE
2) A required DELETE clause
3) An optional OUTPUT clause
4) An optional FROM clause
5) An optional WHERE clause
6) An optional OPTION clause
The DELETE clause of the DELETE statement has three parts
1) Required DELETE keyword
2) Optional FROM keyword
3) Required source
a) Object
b) Alias
Note that the source is either an object or an alias, but not both.
The simplest optional FROM clause contains three parts
1) Required FROM keyword
2) Required object name
3) Optional alias
So there are two different sources for the FROM keyword in a DELETE statement:
1) The optional FROM in the required DELETE clause
2) The required FROM in the optional FROM clause
The DELETE clause can use an alias that is defined in the FROM clause, but it cannot define it's own alias, which is what you are trying to do. You're confusing the two different FROM keywords. In other words, your attempted query can be parsed in one of two ways (both invalid).
DELETE FROM demodelete x WHERE x.somenum = 1;
DELETE <missing required source>
FROM demodelete x
WHERE x.somenum = 1;
DELETE FROM demodelete
<missing required FROM> <missing required object> x
WHERE x.somenum = 1;
Perhaps including all of the optional FROM keywords will help it make sense.
DELETE FROM x
FROM demodelete x
WHERE x.somenum = 1;
Drew
J. Drew Allen
Business Intelligence Analyst
Philadelphia, PA
January 17, 2013 at 10:05 am
Your attached query has a similar problem. The optional FROM clause in a SELECT statement is the same as in a DELETE statement.
1) The FROM keyword is required
2) The object is required
3) The alias is optional
Your EXISTS subquery is missing the required object in the FROM clause. You can easily fix this by moving your derived table x to the EXISTS subquery.
Drew
J. Drew Allen
Business Intelligence Analyst
Philadelphia, PA
Viewing 6 posts - 1 through 5 (of 5 total)
You must be logged in to reply to this topic. Login to reply