SELECT top 1 *
FROM SYSDEPENDENCY
,SYSOBJECT
,SYSPROCPARM
ORDER BY 1, 2, 3, 4, 5
SET OPTION PUBLIC.TEMP_SPACE_LIMIT_CHECK = 'On';
SET OPTION PUBLIC.MAX_TEMP_SPACE = '1G'; -- sets the limit to 1GB
There was an error reading the results of the SQL statement.
The displayed results may be incorrect or incomplete.
Temporary space limit exceeded.
SQLCODE=-1000, ODBC 3 State="HY000"
(SQL 文の実行結果の読み取り時にエラーが発生しました。
表示された実行結果は不正確または不完全である可能性があります。
テンポラリ領域の制限値を超過しました。
SQLCODE=-1000、ODBC 3 State=”HY000″)
CREATE EVENT "evt_monitor_temp_space" TYPE "TempDiskspace"
WHERE EVENT_CONDITION ('TempFreePercent') < 50
HANDLER
BEGIN
-- this event will write a message to console log when there is less
-- than 50% of free space on the device where tempfile is located
declare tf varchar(128);
declare free varchar(128);
declare crn varchar(128);
declare prc varchar(3);
IF event_parameter('NumActive') <= 1 THEN
-- find out temp file name
select convert(varchar(128),(convert(bigint, DB_EXTENDED_PROPERTY('FileSize',
'temporary')) * convert(bigint, PROPERTY('PageSize')) / 1024 / 1024))
into crn from dummy;
-- find out number of available free space
select convert(varchar(128), convert(int, free_space / 1024 / 1024)) into
free from sa_disk_free_space() where dbspace_name = 'temporary';
-- calculate % of free space
if free <> 0 then select
convert(varchar(4), convert(integer, convert(float, crn) /
convert(float, free) * 100)) + '%' into prc from dummy end if;
-- write space information to console log
MESSAGE prc + '(' + crn + ' Mb). of free space (' + free + ' Mb)' + '
have been used by' + tf;
END IF;
END;
0% (214 Mb). of free space (22165 Mb) have been used by C:\DOCUME~1\user_name\LOCALS~1\Temp\asat0001.tmp
2% (558 Mb). of free space (21820 Mb) have been used by C:\DOCUME~1\user_name\LOCALS~1\Temp\asat0001.tmp
Cache size adjusted to 1362112K
4% (974 Mb). of free space (21404 Mb) have been used by C:\DOCUME~1\user_name\LOCALS~1\Temp\asat0001.tmp
4% (1038 Mb). of free space (21340 Mb) have been used by C:\DOCUME~1\user_name\LOCALS~1\Temp\asat0001.tmp
CALL sa_server_option('RememberLastStatement', 'ON');
CALL sa_server_option('RememberLastPlan', 'ON');
if not exists (select * from sysobjects where name like 'sa_tempfile_monitor')
select getdate() as d, db_property('ExtendTempWrite') as ExtendTempWrite,
db_property('TempTablePages') as TempTablePages, prop.Number,
prop.PropNum, prop.PropName, prop.Value,
inf.Name, inf.Userid, inf.LastReqTime, inf.BlockedOn
into sa_tempfile_monitor
from sa_conn_properties() prop, sa_conn_info() inf
where prop.Number = inf.Number and
prop.PropName in
('TempTablePages', 'TempFilePages', 'LastStatement', 'LastPlanText', 'CurrentProcedure', 'CurrentLineNumber')
else
insert into sa_tempfile_monitor
select
getdate(), db_property('ExtendTempWrite'), db_property('TempTablePages'),
prop.Number, prop.PropNum, prop.PropName, prop.Value,
inf.Name, inf.Userid, inf.LastReqTime, inf.BlockedOn
from sa_conn_properties() prop, sa_conn_info() inf
where prop.Number = inf.Number and prop.PropName in
('TempTablePages', 'TempFilePages', 'LastStatement', 'LastPlanText', 'CurrentProcedure', 'CurrentLineNumber')
-- 接続期間ごとのテンポラリファイルの使用率
select d, ExtendTempWrite, TempTablePages, Number, UserID,
convert(Integer, convert(Bigint, Value) / TempTablePages * 100) PerUsage
from sa_tempfile_monitor
where PropName = 'TempTablePages'
order by d, number
SELECT * FROM sa_tempfile_monitor WHERE Number = 2;
"C:\Program Files\SQL Anywhere 16\Bin64\dbsrv16.exe" -zl -zp -m -c 50P
-n demo16 "C:\Documents and settings\All Users\Documents\SQL Anywhere 16\Samples\demo.db"
"C:\Program Files\SQL Anywhere 16\Bin64\dbisql.exe" -c "uid=DBA;pwd=sql;eng=demo16"
SELECT top 1 *
FROM SYSDEPENDENCY,
SYSOBJECT
SYSPROCPARM
ORDER BY 1, 2, 3, 4, 5;
SELECT * FROM sa_conn_properties() WHERE PropName LIKE 'TempTablePages'
ORDER BY CONVERT(integer,value) DESC
You must be a registered user to add a comment. If you've already registered, sign in. Otherwise, register and sign in.
User | Count |
---|---|
14 | |
12 | |
9 | |
9 | |
8 | |
6 | |
6 | |
6 | |
5 | |
5 |