result in text file?

  • I found the script sqlskills site, this is good script for clearing the single user plan as well as remove the wasted memory in buffer cache.

    I want result in text at any system path for analysis purpose, and inside the text file result with datetime, messages. pls. provide the script if anyone done this requirement result in text file.

    if OBJECTPROPERTY(OBJECT_ID('sp_SQLskills_CheckPlanCache'), 'IsProcedure') = 1

    DROP PROCEDURE sp_SQLskills_CheckPlanCache

    go

    CREATE PROCEDURE sp_SQLskills_CheckPlanCache

    (@Percentdecimal(6,3) OUTPUT,

    @WastedMBdecimal(19,3) OUTPUT)

    AS

    SET NOCOUNT ON

    DECLARE @ConfiguredMemorydecimal(19,3)

    , @PhysicalMemorydecimal(19,3)

    , @MemoryInUsedecimal(19,3)

    , @SingleUsePlanCountbigint

    CREATE TABLE #ConfigurationOptions

    (

    [name]nvarchar(35)

    , [minimum]int

    , [maximum]int

    , [config_value]int-- in bytes

    , [run_value]int-- in bytes

    );

    INSERT #ConfigurationOptions EXEC ('sp_configure ''max server memory''');

    SELECT @ConfiguredMemory = run_value/1024/1024

    FROM #ConfigurationOptions

    WHERE name = 'max server memory (MB)'

    SELECT @PhysicalMemory = total_physical_memory_kb/1024

    FROM sys.dm_os_sys_memory

    SELECT @MemoryInUse = physical_memory_in_use_kb/1024

    FROM sys.dm_os_process_memory

    SELECT @WastedMB = sum(cast((CASE WHEN usecounts = 1 AND objtype IN ('Adhoc', 'Prepared')

    THEN size_in_bytes ELSE 0 END) AS DECIMAL(12,2)))/1024/1024

    , @SingleUsePlanCount = sum(CASE WHEN usecounts = 1 AND objtype IN ('Adhoc', 'Prepared')

    THEN 1 ELSE 0 END)

    , @Percent = @WastedMB/@MemoryInUse * 100

    FROM sys.dm_exec_cached_plans

    SELECT[TotalPhysicalMemory (MB)] = @PhysicalMemory

    , [TotalConfiguredMemory (MB)] = @ConfiguredMemory

    , [MaxMemoryAvailableToSQLServer (%)] = @ConfiguredMemory/@PhysicalMemory * 100

    , [MemoryInUseBySQLServer (MB)] = @MemoryInUse

    , [TotalSingleUsePlanCache (MB)] = @WastedMB

    , TotalNumberOfSingleUsePlans = @SingleUsePlanCount

    , [PercentOfConfiguredCacheWastedForSingleUsePlans (%)] = @Percent

    GO

    --EXEC sp_MS_marksystemobject 'sp_SQLskills_CheckPlanCache'

    --go

    -----------------------------------------------------------------

    -- Logic (in a job?) to decide whether or not to clear - using sproc...

    -----------------------------------------------------------------

    DECLARE @Percentdecimal(6, 3)

    , @WastedMBdecimal(19,3)

    , @StrMBnvarchar(20)

    , @StrPercentnvarchar(20)

    EXEC sp_SQLskills_CheckPlanCache @Percent output, @WastedMB output

    SELECT @StrMB = CONVERT(nvarchar(20), @WastedMB)

    , @StrPercent = CONVERT(nvarchar(20), @Percent)

    IF @Percent > 10 OR @WastedMB > 10

    BEGIN

    DBCC FREESYSTEMCACHE('SQL Plans')

    RAISERROR ('%s MB (%s percent) was allocated to single-use plan cache. Single-use plans have been cleared.', 10, 1, @StrMB, @StrPercent)

    END

    ELSE

    BEGIN

    RAISERROR ('Only %s MB (%s percent) is allocated to single-use plan cache - no need to clear cache now.', 10, 1, @StrMB, @StrPercent)

    -- Note: this is only a warning message and not an actual error.

    END

    go

    Thanks

    ananda

  • You could more easily do this via SSIS (whereby you could set the "destination" of the SQL Task to a file destination, setting all kinds of options), however in TSQL you could try something like this:D-ECLARE @FileName varchar(50),

    @bcpCommand varchar(2000)

    INSERT INTO #Results

    EXEC sp_SQLskills_CheckPlanCache @Percent output, @WastedMB output

    SET @FileName = REPLACE('C:\CheckPlanCacheResults_'+ CONVERT(char(8),GETDATE(),1)+'.txt', '/', '-')

    SET @bcpCommand = 'bcp "SELECT * FROM #Results" queryout "' + @FileName + '" -T -c -t,'

    BEGIN TRY

    EXEC xp_cmdshell @bcpCommand

    END TRY

    BEGIN CATCH

    PRINT 'There was an error...'

    END CATCH

    You would need to create a temporary holding table for the results, and "D-ECLARE" typed this way to avoid my proxy snagging the code, so remove the hyphen)

    ______________________________________________________________________________Never argue with an idiot; Theyll drag you down to their level and beat you with experience

  • I tried as below script and executed with no errors for result in create text file but File is not created in C drive. Pls suggestion me

    Create table #Results (

    TotalPhysicalMemory_MB float,

    TotalConfiguredMemory_MB float,

    MaxMemoryAvailableToSQL_pct float,

    TotalSingleUserPlanCache_MB float,

    TotalNumberofSingleUsePlans int,

    Pct_of_configcacheWastedSingleUse float)

    DECLARE @Percentdecimal(6, 3)

    , @WastedMBdecimal(19,3)

    , @StrMBnvarchar(20)

    , @StrPercentnvarchar(20)

    ,@Filename nvarchar(20)

    ,@bcpCommand varchar(2000)

    INSERT INTO #Results select TotalPhysicalMemory_MB,TotalConfiguredMemory_MB,MaxMemoryAvailableToSQL_pct,

    TotalSingleUserPlanCache_MB,TotalNumberofSingleUsePlans,Pct_of_configcacheWastedSingleUse from #Results

    EXEC sp_SQLskills_CheckPlanCache @Percent output, @WastedMB output

    SELECT @StrMB = CONVERT(nvarchar(20), @WastedMB)

    , @StrPercent = CONVERT(nvarchar(20), @Percent)

    IF @Percent > 10 OR @WastedMB > 10

    BEGIN

    DBCC FREESYSTEMCACHE('SQL Plans')

    --RAISERROR ('%s MB (%s percent) was allocated to single-use plan cache. Single-use plans have been cleared.', 10, 1, @StrMB, @StrPercent)

    SET @FileName = REPLACE('C:\CheckPlanCacheResults_'+ CONVERT(char(8),GETDATE(),1)+'.txt', '/', '-')

    SET @bcpCommand = 'bcp "SELECT * FROM #Results" queryout "' + @FileName + '" -T -c -t,'

    -- BEGIN TRY

    EXEC xp_cmdshell @bcpCommand

    END

    ELSE

    BEGIN

    RAISERROR ('Only %s MB (%s percent) is allocated to single-use plan cache - no need to clear cache now.', 10, 1, @StrMB, @StrPercent)

    -- Note: this is only a warning message and not an actual error.

    --END TRY

    END

    drop table #Results

    Thanks

    ananda

  • Silly question, but did you check the C:\ on the computer you ran this from or on the server it is executing against?

    ______________________________________________________________________________Never argue with an idiot; Theyll drag you down to their level and beat you with experience

  • SET @bcpCommand = 'bcp "SELECT * FROM #Results" queryout "' + @FileName + '" -T -c -t,'

    -- BEGIN TRY

    EXEC xp_cmdshell @bcpCommand

    as far as I'm aware bcp will open new connection which will not find your temp table #Results ...

    How you are planing to execute your script? Is it going to be scheduled by some scheduling tool? It may have in-build functionality to dump the results to text file, so simple select * from #Results could do....

    _____________________________________________
    "The only true wisdom is in knowing you know nothing"
    "O skol'ko nam otkrytiy chudnyh prevnosit microsofta duh!":-D
    (So many miracle inventions provided by MS to us...)

    How to post your question to get the best and quick help[/url]

  • Could you not run this as a job and in the job steps advanced tab select "Output File" and specify that way?

  • Eugene, you are quite right and I completely forgot about that. In this case, the OP should just create a physical table and select the results from that (then it could be dropped again).

    I also had a typo in the previous example (an extra "comma") - the example below should work

    Example:C-REATE TABLE MyDatabase.dbo.BcpTest (col1 int, col2 varchar(25))

    INSERT INTO dbo.BcpTest

    SELECT 1, 'Ananda Murugesan' UNION ALL

    SELECT 2, 'MyDoggieJessie' UNION ALL

    SELECT 3, 'Eugene Elutin'

    D-ECLARE @FileName varchar(50), @bcpCommand varchar(2000), @Result varchar(max)

    SET @FileName = REPLACE('C:\CheckPlanCacheResults_' + CONVERT(char(8), GETDATE(), 1) + '.txt', '/', '-')

    SET @bcpCommand = 'bcp "SELECT * FROM MyDatabase.dbo.BcpTest" queryout "' + @FileName + '" -c -S' + RTRIM(@@servername) + ' -T -t '

    BEGIN TRY

    EXEC @result = xp_cmdshell @bcpCommand

    END TRY

    BEGIN CATCH

    PRINT 'There was an error...'

    END CATCH

    D-ROP TABLE MyDatabase.dbo.BcpTest

    ______________________________________________________________________________Never argue with an idiot; Theyll drag you down to their level and beat you with experience

  • There are few things in this design which would make me to reject this solution completely:

    1. Use of xp_cmdshell

    2. Writing file out on SQL Server (or mapped dirve)

    3. Use of permanent table - until adding complexity, it has a risk of reporting crap if for some reason this process runs silmulteniously from mulitple sessions.

    I would stop this proc with populating #Results table and selecting * (or whatever required) from it.

    The caller process should be made responsible for persisting the results.

    _____________________________________________
    "The only true wisdom is in knowing you know nothing"
    "O skol'ko nam otkrytiy chudnyh prevnosit microsofta duh!":-D
    (So many miracle inventions provided by MS to us...)

    How to post your question to get the best and quick help[/url]

  • Of course, you make valid points - 😉 I originally suggested SSIS, but provided a TSQL alternative - not pretty, but there it is...

    ______________________________________________________________________________Never argue with an idiot; Theyll drag you down to their level and beat you with experience

  • MyDoggieJessie (2/10/2014)


    Of course, you make valid points - 😉 I originally suggested SSIS, but provided a TSQL alternative - not pretty, but there it is...

    The use of xp_CmdShell shouldn't be a problem for anyone if it's done correctly and it's pretty easy to do correctly especially security wise.

    --Jeff Moden


    RBAR is pronounced "ree-bar" and is a "Modenism" for Row-By-Agonizing-Row.
    First step towards the paradigm shift of writing Set Based code:
    ________Stop thinking about what you want to do to a ROW... think, instead, of what you want to do to a COLUMN.

    Change is inevitable... Change for the better is not.


    Helpful Links:
    How to post code problems
    How to Post Performance Problems
    Create a Tally Function (fnTally)

  • Jeff Moden (2/10/2014)


    MyDoggieJessie (2/10/2014)


    Of course, you make valid points - 😉 I originally suggested SSIS, but provided a TSQL alternative - not pretty, but there it is...

    The use of xp_CmdShell shouldn't be a problem for anyone if it's done correctly and it's pretty easy to do correctly especially security wise.

    I would agree that, use of xp_CmdShell isn't a problem. However, taking in count much better methods and standard solution designs available nowadays, it would be the last thing i would use, especially for this sort of functionality...

    _____________________________________________
    "The only true wisdom is in knowing you know nothing"
    "O skol'ko nam otkrytiy chudnyh prevnosit microsofta duh!":-D
    (So many miracle inventions provided by MS to us...)

    How to post your question to get the best and quick help[/url]

  • Eugene Elutin (2/10/2014)


    Jeff Moden (2/10/2014)


    MyDoggieJessie (2/10/2014)


    Of course, you make valid points - 😉 I originally suggested SSIS, but provided a TSQL alternative - not pretty, but there it is...

    The use of xp_CmdShell shouldn't be a problem for anyone if it's done correctly and it's pretty easy to do correctly especially security wise.

    I would agree that, use of xp_CmdShell isn't a problem. However, taking in count much better methods and standard solution designs available nowadays, it would be the last thing i would use, especially for this sort of functionality...

    What better methods? SSIS? PoSH? Heh... just because you can do something in SSIS or PoSH, doesn't mean you should. 😀

    --Jeff Moden


    RBAR is pronounced "ree-bar" and is a "Modenism" for Row-By-Agonizing-Row.
    First step towards the paradigm shift of writing Set Based code:
    ________Stop thinking about what you want to do to a ROW... think, instead, of what you want to do to a COLUMN.

    Change is inevitable... Change for the better is not.


    Helpful Links:
    How to post code problems
    How to Post Performance Problems
    Create a Tally Function (fnTally)

  • Jeff Moden (2/10/2014)


    Eugene Elutin (2/10/2014)


    Jeff Moden (2/10/2014)


    MyDoggieJessie (2/10/2014)


    Of course, you make valid points - 😉 I originally suggested SSIS, but provided a TSQL alternative - not pretty, but there it is...

    The use of xp_CmdShell shouldn't be a problem for anyone if it's done correctly and it's pretty easy to do correctly especially security wise.

    I would agree that, use of xp_CmdShell isn't a problem. However, taking in count much better methods and standard solution designs available nowadays, it would be the last thing i would use, especially for this sort of functionality...

    What better methods? SSIS? PoSH? Heh... just because you can do something in SSIS or PoSH, doesn't mean you should. 😀

    It's not point to argue on general use of the xp_cmdshell (with proper security setup).

    For this particular task, in my humble opinion, it is not the best option.

    First of all if using with BCP out, permanent table should be used and some sort of "token" control implemented to allow for concurrent execution, which add unnecessary complexity to the simple logic.

    Actually, xp_CmdShell can directly write data into file (using dos echo), but still I would not want SQL process to create such text/log files on a server...

    Why not just a simple script (in whatever scripting language) which executes proc and outputs into file in a better location.

    This way your proc can be executed ad-hoc to show data on screen (in SSMS), or report can be created based on this proc or whatever... Much more flexible, simpler and robust.

    _____________________________________________
    "The only true wisdom is in knowing you know nothing"
    "O skol'ko nam otkrytiy chudnyh prevnosit microsofta duh!":-D
    (So many miracle inventions provided by MS to us...)

    How to post your question to get the best and quick help[/url]

  • Eugene Elutin (2/11/2014)


    Why not just a simple script (in whatever scripting language) which executes proc and outputs into file in a better location.

    I know it'll be viewed as a personal preference but I try to limit the number of languages used so that you don't need many "experts" nor are you in trouble if the one or two people that use the scripting language leave the company. I'm also adverse to having to use scripts rather than nice, neat stored procedures where I always know where the source code is even if someone screws up SVN.

    --Jeff Moden


    RBAR is pronounced "ree-bar" and is a "Modenism" for Row-By-Agonizing-Row.
    First step towards the paradigm shift of writing Set Based code:
    ________Stop thinking about what you want to do to a ROW... think, instead, of what you want to do to a COLUMN.

    Change is inevitable... Change for the better is not.


    Helpful Links:
    How to post code problems
    How to Post Performance Problems
    Create a Tally Function (fnTally)

Viewing 14 posts - 1 through 13 (of 13 total)

You must be logged in to reply to this topic. Login to reply