Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase «««123

Cursor in Stored Procedure Expand / Collapse
Author
Message
Posted Monday, April 1, 2013 4:49 PM


SSC-Insane

SSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-Insane

Group: General Forum Members
Last Login: Today @ 7:35 PM
Points: 22,992, Visits: 31,471
mister.magoo (4/1/2013)
Lynn Pettis (4/1/2013)


Yea, but I think I'll stick with the FOR XML Version, the following was done against a database with 5147 tables in sys.tables:



---------- opc.three verison ----------
Beginning execution loop
CPU(ms): 73015 Logical Reads: 45463611 Elapsed(ms): 73495 Reads: 3790 Writes: 481191
CPU(ms): 72468 Logical Reads: 45460066 Elapsed(ms): 73294 Reads: 3983 Writes: 483049
CPU(ms): 73015 Logical Reads: 45458216 Elapsed(ms): 73864 Reads: 3886 Writes: 483049
CPU(ms): 72453 Logical Reads: 45458185 Elapsed(ms): 73498 Reads: 4068 Writes: 483050
CPU(ms): 72437 Logical Reads: 45461626 Elapsed(ms): 73262 Reads: 3731 Writes: 483049
Batch execution completed 5 times.
---------- FOR XML PATH Version ----------
Beginning execution loop
CPU(ms): 187 Logical Reads: 79425 Elapsed(ms): 531 Reads: 3477 Writes: 1201
CPU(ms): 187 Logical Reads: 79425 Elapsed(ms): 251 Reads: 3470 Writes: 1201
CPU(ms): 203 Logical Reads: 79425 Elapsed(ms): 414 Reads: 3475 Writes: 1201
CPU(ms): 219 Logical Reads: 79425 Elapsed(ms): 262 Reads: 3466 Writes: 1201
CPU(ms): 172 Logical Reads: 79425 Elapsed(ms): 317 Reads: 3457 Writes: 1201
Batch execution completed 5 times.





Well those poor stats will be improved a bit by reversing the concatenation:

SELECT  @SQLCmd = N'EXEC sys.sp_rename ' + --
'@objname = N''' + SCHEMA_NAME(tab.schema_id) + '.' + tab.name + ''', ' + --
'@newname = N''' + tab.name + '_' + CONVERT(VARCHAR(10), GETDATE(), 112) + ''', ' + --
'@objtype = N''OBJECT'';' + -- OBJECT
NCHAR(13) + NCHAR(10) + @SQLCmd
FROM sys.tables tab;

I don't have a suitably large database to test on , but I am sure you will see some improvement if you test it that way...


Test Harness:


PRINT '---------- mister.magoo verison ----------';
go

set nocount on;
--===== Create the timer and bit-bucket variables and start the timer.
DECLARE @BitBucket sysname; --< change or add variables needed here to eliminate display distortion

Declare @cpu_ int,
@lreads_ bigint,
@eMsec_ bigint,
@Reads_ bigint,
@Writes_ bigint;
declare @CpuMs int,
@LogRds bigint,
@Elapsed bigint,
@Reads bigint,
@Writes bigint;

dbcc freeproccache with no_infomsgs;
dbcc freesystemcache('ALL') with no_infomsgs;
dbcc dropcleanbuffers with no_infomsgs;


Select
@cpu_ = cpu_time
, @lreads_ = logical_reads
, @eMsec_ = total_elapsed_time
, @Reads_ = reads
, @Writes_ = writes
From
sys.dm_exec_requests
Where
session_id = @@spid;

---
DECLARE @SQLCmd NVARCHAR(MAX) = N'';

-- instead of using FOR XML just append the conjured string from each row to the same variable
SELECT @SQLCmd = N'EXEC sys.sp_rename ' + --
'@objname = N''' + SCHEMA_NAME(tab.schema_id) + '.' + tab.name + ''', ' + --
'@newname = N''' + tab.name + '_' + CONVERT(VARCHAR(10), GETDATE(), 112) + ''', ' + --
'@objtype = N''OBJECT'';' + -- OBJECT
NCHAR(13) + NCHAR(10) + @SQLCmd
FROM sys.tables tab;

---

Select
@CpuMs = cpu_time - @cpu_
, @LogRds = logical_reads - @lreads_
, @Elapsed = total_elapsed_time - @eMsec_
, @Reads = reads - @Reads_
, @Writes = writes - @Writes_
From
sys.dm_exec_requests
Where
session_id = @@spid;
--===== Display the duration
PRINT 'CPU(ms): ' + right(' ' + cast(@CpuMs as varchar(10)),10) +
' Logical Reads: ' + right(' ' + cast(@LogRds as varchar(10)),10) +
' Elapsed(ms): ' + right(' ' + cast(@Elapsed as varchar(10)),10) +
' Reads: ' + right(' ' + cast(@Reads as varchar(10)),10) +
' Writes: ' + right(' ' + cast(@Writes as varchar(10)),10);

set nocount off;
GO 5
set nocount on;

PRINT '---------- FOR XML PATH Version ----------';
go

--===== Create the timer and bit-bucket variables and start the timer.
DECLARE @BitBucket sysname; --< change or add variables needed here to eliminate display distortion

Declare @cpu_ int,
@lreads_ bigint,
@eMsec_ bigint,
@Reads_ bigint,
@Writes_ bigint;
declare @CpuMs int,
@LogRds bigint,
@Elapsed bigint,
@Reads bigint,
@Writes bigint;

dbcc freeproccache with no_infomsgs;
dbcc freesystemcache('ALL') with no_infomsgs;
dbcc dropcleanbuffers with no_infomsgs;


Select
@cpu_ = cpu_time
, @lreads_ = logical_reads
, @eMsec_ = total_elapsed_time
, @Reads_ = reads
, @Writes_ = writes
From
sys.dm_exec_requests
Where
session_id = @@spid;

---
declare @SQLCmd nvarchar(max);

select
@SQLCmd = stuff((select char(13) + char(10) +
'exec sp_rename @objname = N''' + schema_name(tab.schema_id) +
'.' + tab.name + ''', @newname = N''' + schema_name(tab.schema_id) +
'.' + tab.name + '_' + convert(varchar(10), getdate(), 112) + ''', @objtype = N''TABLE'''
from sys.tables tab
for xml path(''),TYPE).value('.','nvarchar(max)'),1,2,'');

---

Select
@CpuMs = cpu_time - @cpu_
, @LogRds = logical_reads - @lreads_
, @Elapsed = total_elapsed_time - @eMsec_
, @Reads = reads - @Reads_
, @Writes = writes - @Writes_
From
sys.dm_exec_requests
Where
session_id = @@spid;
--===== Display the duration
PRINT 'CPU(ms): ' + right(' ' + cast(@CpuMs as varchar(10)),10) +
' Logical Reads: ' + right(' ' + cast(@LogRds as varchar(10)),10) +
' Elapsed(ms): ' + right(' ' + cast(@Elapsed as varchar(10)),10) +
' Reads: ' + right(' ' + cast(@Reads as varchar(10)),10) +
' Writes: ' + right(' ' + cast(@Writes as varchar(10)),10);

set nocount off;
GO 5


Results:


---------- mister.magoo verison ----------
Beginning execution loop
CPU(ms): 72125 Logical Reads: 45047659 Elapsed(ms): 72511 Reads: 4053 Writes: 483074
CPU(ms): 72953 Logical Reads: 45048223 Elapsed(ms): 73248 Reads: 3830 Writes: 483074
CPU(ms): 72781 Logical Reads: 45047945 Elapsed(ms): 73238 Reads: 3993 Writes: 483074
CPU(ms): 72250 Logical Reads: 45049884 Elapsed(ms): 72838 Reads: 4254 Writes: 483075
CPU(ms): 72312 Logical Reads: 45051235 Elapsed(ms): 72734 Reads: 3727 Writes: 483075
Batch execution completed 5 times.
---------- FOR XML PATH Version ----------
Beginning execution loop
CPU(ms): 203 Logical Reads: 80643 Elapsed(ms): 381 Reads: 3464 Writes: 1238
CPU(ms): 203 Logical Reads: 80641 Elapsed(ms): 271 Reads: 3464 Writes: 1240
CPU(ms): 203 Logical Reads: 80639 Elapsed(ms): 267 Reads: 3464 Writes: 1238
CPU(ms): 187 Logical Reads: 80637 Elapsed(ms): 275 Reads: 3464 Writes: 1240
CPU(ms): 219 Logical Reads: 80637 Elapsed(ms): 269 Reads: 3464 Writes: 1240
Batch execution completed 5 times.



Is this what you expected?



Lynn Pettis

For better assistance in answering your questions, click here
For tips to get better help with Performance Problems, click here
For Running Totals and its variations, click here or when working with partitioned tables
For more about Tally Tables, click here
For more about Cross Tabs and Pivots, click here and here
Managing Transaction Logs

SQL Musings from the Desert Fountain Valley SQL (My Mirror Blog)
Post #1437655
Posted Monday, April 1, 2013 4:57 PM


SSC-Insane

SSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-Insane

Group: General Forum Members
Last Login: Today @ 7:35 PM
Points: 22,992, Visits: 31,471
opc.three (4/1/2013)
That seems to be a function of continually updating an NVARCHAR(MAX) which does not scale linearly. It gets truncated so it's worthless to use it but if you run the same code with an NVARCHAR(4000) it keeps up.

There is no question the XML method offers a nice performance improvement Lynn but I think the measurements are off. When I run this on a DB with ~600 tables my query finishes in 70ms and yours in 5ms, yet your measurement shows 47901ms and there is no way that's correct given that my machine only has 8 CPUs.

I find the variable-method a little easier to read (personal pref) and am not going to worry all that much about how long one of these kinds of queries is going to run mainly because performance working with DDL like this has never been too much of a concern for me. If a cursor is easier in this context it's one of the few places where I would use one, not for performance or readbility though, for the row-by-row error-handling option it offers that Erin mentioned. To each their own.

A couple things I tweaked in the original code that I thought should be fixed in the other samples, just in case someone tried to copy it and run off to use it, so I'll call them out here since I think they went unnoticed:

1. This snip:

@newname = N''' + schema_name(tab.schema_id) + '.' +  tab.name

should have the schema name removed from the new name else you end up with tables named like [dbo].[dbo.table_20130401]

2. @objtype = N'TABLE' should be changed to @objtype = N'OBJECT'



I'll give you the @objtype change as something to be corrected, and the second as I just reread ap_rename. Now, how to deal with multiple schemas??

Without testing, does the new table name keep the old table name's schema?



Lynn Pettis

For better assistance in answering your questions, click here
For tips to get better help with Performance Problems, click here
For Running Totals and its variations, click here or when working with partitioned tables
For more about Tally Tables, click here
For more about Cross Tabs and Pivots, click here and here
Managing Transaction Logs

SQL Musings from the Desert Fountain Valley SQL (My Mirror Blog)
Post #1437658
Posted Monday, April 1, 2013 4:58 PM


SSCommitted

SSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommitted

Group: General Forum Members
Last Login: Today @ 4:21 PM
Points: 1,780, Visits: 5,644
Lynn, Nope that pretty much sucks too!

MM


  • MMGrid Addin
  • MMNose Addin


  • Forum Etiquette: How to post Reporting Services problems
  • Forum Etiquette: How to post data/code on a forum to get the best help - by Jeff Moden
  • How to Post Performance Problems - by Gail Shaw

  • Post #1437659
    Posted Monday, April 1, 2013 5:02 PM


    SSCertifiable

    SSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiable

    Group: General Forum Members
    Last Login: Yesterday @ 4:52 PM
    Points: 7,079, Visits: 12,569
    I'll give you the @objtype change as something to be corrected, and the second as I just reread ap_rename. Now, how to deal with multiple schemas??

    Without testing, does the new table name keep the old table name's schema?

    Yes. Schemas are handled the way mine was written. No need to re-qualify anything. The @objname finds the object, and the @newname is the new name of the object within that schema.


    __________________________________________________________________________________________________
    There are no special teachers of virtue, because virtue is taught by the whole community. --Plato
    Post #1437660
    Posted Monday, April 1, 2013 5:03 PM


    SSCertifiable

    SSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiable

    Group: General Forum Members
    Last Login: Yesterday @ 4:52 PM
    Points: 7,079, Visits: 12,569
    mister.magoo (4/1/2013)
    Lynn, Nope that pretty much sucks too!

    Lynn's numbers seem off to me. I got ~10s for your method and ~50ms for Lynns. But Lynn's numbers make it look waaaay worse. I am wondering Lynn if your numbers are in nanoseconds?


    __________________________________________________________________________________________________
    There are no special teachers of virtue, because virtue is taught by the whole community. --Plato
    Post #1437661
    Posted Monday, April 1, 2013 5:04 PM


    SSC-Insane

    SSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-Insane

    Group: General Forum Members
    Last Login: Today @ 7:35 PM
    Points: 22,992, Visits: 31,471
    opc.three (4/1/2013)
    I'll give you the @objtype change as something to be corrected, and the second as I just reread ap_rename. Now, how to deal with multiple schemas??

    Without testing, does the new table name keep the old table name's schema?

    Yes. Schemas are handled the way mine was written. No need to re-qualify anything. The @objname finds the object, and the @newname is the new name of the object within that schema.


    Good. I don't use sp_rename often and actually everything in our databases here resides in the dbo schema.

    Now, just hit myself over the head a few times with this information and perhaps it will reach the long term memory where I will have no trouble recalling.



    Lynn Pettis

    For better assistance in answering your questions, click here
    For tips to get better help with Performance Problems, click here
    For Running Totals and its variations, click here or when working with partitioned tables
    For more about Tally Tables, click here
    For more about Cross Tabs and Pivots, click here and here
    Managing Transaction Logs

    SQL Musings from the Desert Fountain Valley SQL (My Mirror Blog)
    Post #1437662
    Posted Monday, April 1, 2013 5:23 PM


    SSCommitted

    SSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommitted

    Group: General Forum Members
    Last Login: Today @ 4:21 PM
    Points: 1,780, Visits: 5,644
    opc.three (4/1/2013)
    mister.magoo (4/1/2013)
    Lynn, Nope that pretty much sucks too!

    Lynn's numbers seem off to me. I got ~10s for your method and ~50ms for Lynns. But Lynn's numbers make it look waaaay worse. I am wondering Lynn if your numbers are in nanoseconds?


    No, they seem about right in terms of scale - I have seen massive improvements in the past from appending the MAX variable to the calculated string, rather than appending the string to the MAX variable, but not in this case. Celery.


    MM


  • MMGrid Addin
  • MMNose Addin


  • Forum Etiquette: How to post Reporting Services problems
  • Forum Etiquette: How to post data/code on a forum to get the best help - by Jeff Moden
  • How to Post Performance Problems - by Gail Shaw

  • Post #1437665
    Posted Monday, April 1, 2013 11:12 PM


    SSC-Insane

    SSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-Insane

    Group: General Forum Members
    Last Login: Today @ 7:35 PM
    Points: 22,992, Visits: 31,471
    opc.three (4/1/2013)
    mister.magoo (4/1/2013)
    Lynn, Nope that pretty much sucks too!

    Lynn's numbers seem off to me. I got ~10s for your method and ~50ms for Lynns. But Lynn's numbers make it look waaaay worse. I am wondering Lynn if your numbers are in nanoseconds?


    CPU time and Elapsed time are in milliseconds. Plus, sitting there watching the code run, it is pretty accurate.



    Lynn Pettis

    For better assistance in answering your questions, click here
    For tips to get better help with Performance Problems, click here
    For Running Totals and its variations, click here or when working with partitioned tables
    For more about Tally Tables, click here
    For more about Cross Tabs and Pivots, click here and here
    Managing Transaction Logs

    SQL Musings from the Desert Fountain Valley SQL (My Mirror Blog)
    Post #1437696
    Posted Monday, April 1, 2013 11:41 PM


    SSC-Insane

    SSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-Insane

    Group: General Forum Members
    Last Login: Today @ 7:35 PM
    Points: 22,992, Visits: 31,471
    opc.three (4/1/2013)
    mister.magoo (4/1/2013)
    Lynn, Nope that pretty much sucks too!

    Lynn's numbers seem off to me. I got ~10s for your method and ~50ms for Lynns. But Lynn's numbers make it look waaaay worse. I am wondering Lynn if your numbers are in nanoseconds?


    Also, the difference could be the size of the string as it is concatenated. The table names in the database I used can get a bit long in the tooth.



    Lynn Pettis

    For better assistance in answering your questions, click here
    For tips to get better help with Performance Problems, click here
    For Running Totals and its variations, click here or when working with partitioned tables
    For more about Tally Tables, click here
    For more about Cross Tabs and Pivots, click here and here
    Managing Transaction Logs

    SQL Musings from the Desert Fountain Valley SQL (My Mirror Blog)
    Post #1437706
    Posted Tuesday, April 2, 2013 12:11 PM


    SSCertifiable

    SSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiable

    Group: General Forum Members
    Last Login: Yesterday @ 4:52 PM
    Points: 7,079, Visits: 12,569
    Just for fun I wanted to see how a CLR might stack up so I ran it through GROUP_CONCAT against 5000 tables with an average length of ~115 characters:

    Version using XML with a couple of the discussed tweaks:

    SELECT  @SQLCmd = STUFF((SELECT CHAR(13) + CHAR(10) + --
    'EXEC sys.sp_rename @objname = N''' + SCHEMA_NAME(tab.schema_id) + '.' + tab.name + ''', ' + --
    '@newname = N''' + tab.name + '_' + CONVERT(VARCHAR(10), GETDATE(), 112) + ''', ' + --
    '@objtype = N''OBJECT'';'
    FROM sys.tables tab
    FOR XML PATH(''),
    TYPE).value('.', 'nvarchar(max)'), 1, 2, '');

    Version using CLR:

    SELECT  @SQLCmd = GroupConcatTest.dbo.group_concat_d(N'EXEC sys.sp_rename ' + --
    N'@objname = N''' + SCHEMA_NAME(tab.schema_id) + N'.' + tab.name + N''', ' + --
    N'@newname = N''' + tab.name + N'_' + @dt + N''', ' + --
    N'@objtype = N''OBJECT''', N';' + NCHAR(13) + NCHAR(10))
    FROM sys.tables tab;

    ---------- opc.three CLR version ----------

    SQL Server Execution Times:
    CPU time = 140 ms, elapsed time = 240 ms.
    ---------- FOR XML PATH Version ----------

    SQL Server Execution Times:
    CPU time = 78 ms, elapsed time = 108 ms.


    __________________________________________________________________________________________________
    There are no special teachers of virtue, because virtue is taught by the whole community. --Plato
    Post #1438043
    « Prev Topic | Next Topic »

    Add to briefcase «««123

    Permissions Expand / Collapse