Showing posts with label temp tables. Show all posts
Showing posts with label temp tables. Show all posts

Sunday, August 27, 2017

Why would anyone use a global temporary table?



SQL Azure has added something called database scoped global temporary tables.

Azure SQL Database supports global temporary tables that are also stored in tempdb and scoped to the database level. This means that global temporary tables are shared for all users’ sessions within the same Azure SQL database. User sessions from other Azure SQL databases cannot access global temporary tables.

They way you add these is by using a double pound sign

They way you create a database scoped global temporary table is like this

CREATE TABLE ##test ( a int, b int);

You are probably thinking...wait a minute, how is this different from a global temporary table? It is pretty much the same but on SQL Azure, it is scoped to the database level, while on prem it is scoped to the instance level


I was listening to the latest SQL Server Radio podcast and the hosts were talking about why anyone would ever need a global temporary table. Why not use a real table instead

I can come up with one answer....

Let's take a look

First create a database and then add a user who has read and write permissions


CREATE DATABASE Test
GO

CREATE LOGIN DenisTest   
    WITH PASSWORD = 'DenisTest', CHECK_EXPIRATION=OFF, CHECK_POLICY=OFF; 

USE Test
GO

CREATE USER DenisTest FOR LOGIN DenisTest;  
GO   

ALTER ROLE [db_datareader] ADD MEMBER DenisTest
GO
ALTER ROLE [db_datawriter] ADD MEMBER DenisTest
GO

Now, let say we want to run a query several times and store the results



USE Test
GO

SELECT name,type_desc,state_desc,size
FROM sys.database_files
WHERE name ='Test'

So I need a table to store the results right?
Let's try creating one......

CREATE TABLE SomeTable (name sysname,
type_desc nvarchar(120),
state_desc nvarchar(120),
size int)

Msg 262, Level 14, State 1, Line 8
CREATE TABLE permission denied in database 'Test'.

That is right, we don't have permissions

Now let's add a double pound sign in front of that table

CREATE TABLE ##SomeTable (name sysname,
type_desc nvarchar(120),
state_desc nvarchar(120),
size int)

And this works

Now we can insert into the table we just created

INSERT ##SomeTable
SELECT name,type_desc,state_desc,size
FROM sys.database_files
WHERE name ='Test'

Also, we can insert and select from other sessions.query windows as well

Of course if the server restarts, this table will be gone. However if you want to capture some query output and look at it, you don't have to wait for someone to give you ddl_admin permission, create the table for you or make you db_owner.


Now why everyone would need a temporary stored procedure...that is another story and I can't really think of a reason









Wednesday, September 09, 2015

Dealing with temporary tables and named constraints



The other day one of our recently changed stored procedures in the development environment started to fail with a message like the following


There is already an object named 'PK_#SomeName' in the database.

I looked at the proc code and noticed something like the following


ALTER TABLE #test ADD CONSTRAINT PK_#test PRIMARY KEY CLUSTERED (id)



Books On Line specifies the following about constraint names


constraint_name

Is the name of a constraint. Constraint names must be unique within the schema to which the table belongs.


Before I give you an example of how you can get around this, let's first see how it breaks

Copy and paste the following code in a window in SQL Server Management Studio, execute the code below

CREATE TABLE #test (id int not null)


ALTER TABLE #test ADD CONSTRAINT PK_#test PRIMARY KEY CLUSTERED (id)

Now take the same exact code, paste it in a new window (use the same database) and execute it, you should see the following error

Msg 2714, Level 16, State 5, Line 3
There is already an object named 'PK_#test' in the database.
Msg 1750, Level 16, State 0, Line 3
Could not create constraint. See previous errors.


As you can see the message clearly tells you that there is already an object with that name in the database. So how can you get around this? There are two ways, the first is to use an unnamed constraint

Open a new window and execute the following

CREATE TABLE #test (id int NOT NULL, PRIMARY KEY (id))
)

You can now do this in a couple of new windows and it won't fail.

Just to prove that the constraint works as expected, run the following code in some of those windows

INSERT #test VALUES(1)
INSERT #test VALUES(1)

You will get a message similar to the one below

Msg 2627, Level 14, State 1, Line 1
Violation of PRIMARY KEY constraint 'PK__#test_____3213E83F8E75389B'. Cannot insert duplicate key in object 'dbo.#test'. The duplicate key value is (1).
The statement has been terminated.


Instead of a primary key, you could also use a unique index. Contrary to constraints names, index names do not have to be unique within the schema to which the table belongs

You can run the following code in a couple of windows and it won't fail

CREATE TABLE #test (id int not null)

CREATE UNIQUE CLUSTERED INDEX PK_#test on #test(id)

If you run the code below you will see that it will fail on the second insert

INSERT #test VALUES(1)

INSERT #test VALUES(1)


Here is the expected error message


Msg 2601, Level 14, State 1, Line 1
Cannot insert duplicate key row in object 'dbo.#test' with unique index 'PK_#test'. The duplicate key value is (1).
The statement has been terminated.

So to sum it up, do NOT use named constraint with temporary tables, especially not inside stored procedures, if two sessions run the same proc you will get a failure


Use unnamed constraints or use a unique index on a non nullable column instead