Skip to content
GitLab
Projects
Groups
Snippets
/
Help
Help
Support
Community forum
Keyboard shortcuts
?
Submit feedback
Contribute to GitLab
Sign in
Toggle navigation
Menu
Open sidebar
dwentzel
SQLScripts
Commits
32c58f8f
Commit
32c58f8f
authored
Jun 17, 2015
by
dwentzel
Browse files
added LinkedServerGenerator.sql
parent
ab75953d
Changes
2
Hide whitespace changes
Inline
Side-by-side
LinkedServerGenerator.sql
0 → 100644
View file @
32c58f8f
IF
EXISTS
(
select
*
from
sys
.
objects
where
object_id
=
object_id
(
'LinkedServerGenerator'
))
DROP
PROCEDURE
LinkedServerGenerator
;
GO
CREATE
PROCEDURE
LinkedServerGenerator
(
@
Action
varchar
(
200
)
--CREATE/DESTROY
,
@
LinkedServerName
varchar
(
2000
)
,
@
DataSource
varchar
(
2000
)
=
NULL
,
@
rmtuser
varchar
(
2000
)
,
@
rmtpassword
varchar
(
2000
)
)
WITH
ENCRYPTION
AS
BEGIN
/*
This procedure sets up and destroys the linked server
This should be deployed in the local database
*/
IF
@
Action
=
'DESTROY'
BEGIN
IF
EXISTS
(
SELECT
*
FROM
sys
.
servers
WHERE
name
=
@
LinkedServerName
)
BEGIN
EXEC
master
..
sp_droplinkedsrvlogin
@
rmtsrvname
=
@
LinkedServerName
,
@
locallogin
=
NULL
;
EXEC
master
..
sp_dropserver
@
server
=
@
LinkedServerName
;
END
;
RETURN
0
;
END
;
--this block is for CREATE
--cleanup...just in case
EXEC
LinkedServerGenerator
@
Action
=
'DESTROY'
;
--build linked server
EXEC
sp_addlinkedserver
@
server
=
@
LinkedServerName
,
@
srvproduct
=
N
'DoesNotMatter'
,
@
provider
=
N
'SQLNCLI'
,
@
datasrc
=
@
DataSource
;
EXEC
sp_serveroption
@
server
=
@
LinkedServerName
,
@
optname
=
N
'remote proc transaction promotion'
,
@
optvalue
=
'FALSE'
;
--When FALSE calling a remote stored procedure does NOT start a distributed transaction
EXEC
sp_serveroption
@
server
=
@
LinkedServerName
,
@
optname
=
N
'rpc'
,
@
optvalue
=
'TRUE'
;
EXEC
sp_serveroption
@
server
=
@
LinkedServerName
,
@
optname
=
N
'RPC OUT'
,
@
optvalue
=
'TRUE'
;
EXEC
sp_serveroption
@
server
=
@
LinkedServerName
,
@
optname
=
N
'collation compatible'
,
@
optvalue
=
N
'false'
;
EXEC
sp_serveroption
@
server
=
@
LinkedServerName
,
@
optname
=
N
'data access'
,
@
optvalue
=
N
'true'
;
EXEC
sp_serveroption
@
server
=
@
LinkedServerName
,
@
optname
=
N
'connect timeout'
,
@
optvalue
=
N
'0'
;
EXEC
sp_serveroption
@
server
=
@
LinkedServerName
,
@
optname
=
N
'collation name'
,
@
optvalue
=
null
;
EXEC
sp_serveroption
@
server
=
@
LinkedServerName
,
@
optname
=
N
'query timeout'
,
@
optvalue
=
N
'0'
;
EXEC
sp_serveroption
@
server
=
@
LinkedServerName
,
@
optname
=
N
'use remote collation'
,
@
optvalue
=
N
'true'
;
EXEC
master
.
dbo
.
sp_addlinkedsrvlogin
@
rmtsrvname
=
@
LinkedServerName
,
@
useself
=
'false'
,
@
locallogin
=
NULL
,
@
rmtuser
=
@
rmtuser
,
@
rmtpassword
=
@
rmtpassword
;
END
;
GO
/*
Tests:
EXEC LinkedServerGenerator @Action='DESTROY';
EXEC LinkedServerGenerator @Action='CREATE', @DataSource = '.\SQL2014';
EXEC LinkedServerGenerator @Action='DESTROY';
*/
\ No newline at end of file
README.MD
View file @
32c58f8f
...
...
@@ -29,7 +29,11 @@ jobs. Includes tsqlt unit tests.
`CreateSnapshot.sql`
: http://www.davewentzel.com/content/automatic-database-snapshot-creation-script.
Quickly creates a database snapshot and provides you with the commands to restore the db back to the snapshot.
This is great when testing some code (not in prod) where transaction control may not be possible (such as testing
service broker features or replication). This will allow you to quickly "roll back" any changes.
service broker features or replication). This will allow you to quickly "roll back" any changes.
`LinkedServerGenerator.sql`
: Dyanmically creates or destroys a linked server. This is useful to "build your own
connection string". Specifically in dev envs where you may need to quickly copy some data from another server using
"INSERT INTO...SELECT".
`PostRestoreSteps.sql`
: http://www.davewentzel.com/content/post-restore-process. Train your staff to always
run this proc as part of their environment build and db restore process and you'll ensure your environment
...
...
Write
Preview
Supports
Markdown
0%
Try again
or
attach a new file
.
Cancel
You are about to add
0
people
to the discussion. Proceed with caution.
Finish editing this message first!
Cancel
Please
register
or
sign in
to comment