Identifying Space Issues by Querying System Views - Teradata Database

Teradata Database Administration

Product
Teradata Database
Release Number
15.10
Language
English (United States)
Last Update
2018-10-06
Product Category
Software

Querying the DiskSpaceV View to Find System Space Issues

The DBC.DiskSpaceV view returns AMP information about disk space usage at the database or user level. It also can report spool space usage. DiskSpaceV figures are calculated only for the space owned by the user submitting the query. To find information about the full system, log on as the topmost user in the hierarchy (usually your site administrative user).

You can determine the amount of space allocated to a profile by querying the MaxProfileSpool and MaxProfileTemp columns of DBC.DiskSpaceV. By querying MaxSpool and MaxTemp of the restricted view (DBC.DiskSpaceVX), you get the space limits for your individual user space. The following queries show the kinds of information you can obtain from DBC.DiskSpaceV.

 

TO find the…

SUBMIT the following query…

total disk space in the entire system

SELECT SUM(MaxPerm) FROM DBC.DiskSpaceV;

disk space currently in use

SELECT SUM(CurrentPerm),
       SUM(MaxPerm),
       ((SUM(currentperm) / NULLIFZERO(SUM(maxperm)) * 100))
       (TITLE '%MaxPerm', FORMAT 'zz9.99')
FROM DBC.DiskSpaceV;

disk space for a given database

SELECT sum(maxperm
FROM DBC.DiskSpaceV WHERE databasename='xxxx';

percent of disk space that is available for spool

SELECT (((SUM(MaxPerm) - SUM(CurrentPerm)) / NULLIFZERO(SUM(MaxPerm))) * 100)
(TITLE'% Avail for Spool', format'zz9.99')
FROM DBC.DiskSpaceV;

percent of space used by each database in the system

SELECT Databasename (format 'X(12)')
,SUM(maxperm)
,SUM(currentperm)
,((SUM(currentperm))/
NULLIFZERO (SUM(maxperm)) * 100)
(FORMAT 'zz9.99%', TITLE 'Percent // Used')
FROM DBC.DiskSpaceV
GROUP BY 1
ORDER BY 4 DESC
WITH SUM (currentperm), SUM(maxperm);

users who are running out of PERM space

SELECT Databasename (format 'X(12)')
,SUM(maxperm)
,SUM(currentperm)
,((SUM(currentperm))/
NULLIFZERO (SUM(maxperm)) * 100)
(format 'zz9.99%', TITLE 'Percent // Used')
FROM DBC.DiskSpaceV
GROUP BY 1 HAVING (SUM(currentPerm) / NULLIFZERO(SUM(maxperm))) > 0.9
ORDER BY 4 DESC;

users using a lot of spool

SELECT databasename
,SUM(peakspool)
FROM DBC.DiskSpaceV
GROUP BY 1 HAVING SUM(peakspool) > 5000000000
ORDER BY 2 DESC;

Note: You can change the value 500000000 to whatever value is appropriate for your site. Some sites with more space may have higher tolerance for higher spool usage and spool limits.