Rapor

Oracle Veritabanında Alınan RMAN Yedeklerinin Listesi

Bundan önce alınan rman yedeklerinin listesini veren yararlı bir script.

SET LINES 110
SET PAGES 20
COLUMN "Start Data" FOR a20
COLUMN "End Date" FOR a20
COLUMN "Time Minute" FORMAT a15
COLUMN status FORMAT a11
COLUMN input_bytes_display FORMAT a10
COLUMN output_bytes_display FORMAT a10

TITLE CENTER RMAN_Backup_List_REPORT SKIP 2

  SELECT TO_CHAR (start_time, 'YYYY.MM.DD HH24:MI:SS') "Start Data",
         TO_CHAR (end_time, 'YYYY.MM.DD HH24:MI:SS') "End Date",
         TO_CHAR (ROUND ( (end_time - start_time) * 24 * 60)) || ' dk'
            "Time Minute",
         status,
         input_type,
         input_bytes_display,
         output_bytes_display
    FROM V$RMAN_BACKUP_JOB_DETAILS
   WHERE (start_time BETWEEN (SYSDATE - 12) AND (SYSDATE))
ORDER BY start_time;

Yararlı olması Dilegiyle…
Yazar : Mustafa Bektaş Tepe

1,256 total views, no views today


Veritabanı Tablespace Bilgisi için Script

Merhabalar aşagıda ki sorgu veritabanımızda ki tablespaceler hakkında ayrıntılı bilgi veriyor.

Sorgu 1 :

SET PAGESIZE 100
SET LINESIZE 160
COLUMN "Tablespace Name" FORMAT a30
COLUMN "TS Used GB" FORMAT 9999
COLUMN "TS Alloc. GB" FORMAT 9999
COLUMN "TS Free GB" FORMAT 9999
COLUMN "Pct Used  %" FORMAT 9999
COLUMN "TS Max GB" FORMAT 9999
COLUMN "TS Max Free GB" FORMAT 9999
COLUMN "Pct Max. Used %" FORMAT 9999

SELECT a.tablespace_name "Tablespace Name",
       ROUND ( (a.bytes_alloc - NVL (b.bytes_free, 0)) / 1024 / 1024 / 1024)
          "TS Used GB",
       ROUND (a.bytes_alloc / 1024 / 1024 / 1024) "TS Alloc. GB",
       ROUND (NVL (b.bytes_free, 0) / 1024 / 1024 / 1024) "TS Free GB",
       100 - ROUND ( (NVL (b.bytes_free, 0) / a.bytes_alloc) * 100)
          "Pct Used  %",
       ROUND (maxbytes / 1073741824) "TS Max GB",
       ROUND (
          (maxbytes - (a.bytes_alloc - NVL (b.bytes_free, 0))) / 1073741824)
          "TS Max Free GB",
       ROUND (
          ( (ROUND ( (a.bytes_alloc - NVL (b.bytes_free, 0))))
           / ( (ROUND (maxbytes)) / 100)))
          "Pct Max. Used %"
  FROM (  SELECT f.tablespace_name,
                 SUM (f.bytes) bytes_alloc,
                 SUM (
                    DECODE (f.autoextensible,
                            'YES', f.maxbytes,
                            'NO', f.bytes))
                    maxbytes
            FROM dba_data_files f
        GROUP BY tablespace_name) a,
       (  SELECT f.tablespace_name, SUM (f.bytes) bytes_free
            FROM dba_free_space f
        GROUP BY tablespace_name) b
 WHERE a.tablespace_name = b.tablespace_name(+)
UNION ALL
  SELECT h.tablespace_name "Tablespace Name",
         ROUND (SUM (NVL (p.bytes_used, 0)) / 1073741824) "TS Used GB",
         ROUND (SUM (h.bytes_free + h.bytes_used) / 1073741824) "TS Alloc. GB",
         ROUND (
            SUM ( (h.bytes_free + h.bytes_used) - NVL (p.bytes_used, 0))
            / 1073741824)
            "TS Free GB",
         100
         - ROUND (
              (SUM ( (h.bytes_free + h.bytes_used) - NVL (p.bytes_used, 0))
               / SUM (h.bytes_used + h.bytes_free))
              * 100)
            "Pct Used  %",
         ROUND (SUM (f.maxbytes) / 1073741824) "TS Max GB",
         ROUND (
            (SUM (f.maxbytes) - (SUM (NVL (p.bytes_used, 0)))) / 1073741824)
            "TS Max Free GB",
         ROUND (
            ( (ROUND (SUM (NVL (p.bytes_used, 0))))
             / ( (ROUND (SUM (f.maxbytes))) / 100)))
            "Pct Max. Used %"
    FROM sys.v_$TEMP_SPACE_HEADER h,
         sys.v_$Temp_extent_pool p,
         dba_temp_files f
   WHERE     p.file_id(+) = h.file_id
         AND p.tablespace_name(+) = h.tablespace_name
         AND f.file_id = h.file_id
         AND f.tablespace_name = h.tablespace_name
GROUP BY h.tablespace_name
ORDER BY 8 DESC;

Sorgu 2 : 

SET LINES 132 PAGES 66 FEEDBACK OFF
COLUMN tablespace_name        FORMAT a15             HEADING 'Tablespace|(TBS)|Name'
COLUMN autoextensible         FORMAT a6              HEADING 'Can|Auto|Extend'
COLUMN files_in_tablespace    FORMAT 999             HEADING 'Files|In|TBS'
COLUMN total_tablespace_space FORMAT 99,999,999,999 HEADING 'Total|Current|TBS|Space'
COLUMN total_used_space       FORMAT 99,999,999,999 HEADING 'Total|Current|Used|Space'
COLUMN total_tablespace_free_space FORMAT 99,999,999,999 HEADING 'Total|Current|Free|Space'
COLUMN total_used_pct              FORMAT 999.99      HEADING 'Total|Current|Used|PCT'
COLUMN total_free_pct              FORMAT 999.99      HEADING 'Total|Current|Free|PCT'
COLUMN max_size_of_tablespace      FORMAT 99,999,999,999 HEADING 'TBS|Max|Size'
COLUMN total_auto_used_pct         FORMAT 999.99      HEADING 'Total|Max|Used|PCT'
COLUMN total_auto_free_pct         FORMAT 999.99      HEADING 'Total|Max|Free|PCT'

TTITLE LEFT _date CENTER Tablespace SPACE Utilization Status REPORT SKIP 2

WITH tbs_auto
     AS (SELECT DISTINCT tablespace_name, autoextensible
           FROM dba_data_files
          WHERE autoextensible = 'YES'),
     files
     AS (  SELECT tablespace_name,
                  COUNT (*) tbs_files,
                  SUM (BYTES) total_tbs_bytes
             FROM dba_data_files
         GROUP BY tablespace_name),
     fragments
     AS (  SELECT tablespace_name,
                  COUNT (*) tbs_fragments,
                  SUM (BYTES) total_tbs_free_bytes,
                  MAX (BYTES) max_free_chunk_bytes
             FROM dba_free_space
         GROUP BY tablespace_name),
     AUTOEXTEND
     AS (  SELECT tablespace_name, SUM (size_to_grow) total_growth_tbs
             FROM (  SELECT tablespace_name, SUM (maxbytes) size_to_grow
                       FROM dba_data_files
                      WHERE autoextensible = 'YES'
                   GROUP BY tablespace_name
                   UNION
                     SELECT tablespace_name, SUM (BYTES) size_to_grow
                       FROM dba_data_files
                      WHERE autoextensible = 'NO'
                   GROUP BY tablespace_name)
         GROUP BY tablespace_name)
SELECT a.tablespace_name,
       CASE tbs_auto.autoextensible WHEN 'YES' THEN 'YES' ELSE 'NO' END
          AS autoextensible,
       files.tbs_files files_in_tablespace,
       files.total_tbs_bytes / 1024 / 1024 total_tablespace_space,
       (files.total_tbs_bytes - fragments.total_tbs_free_bytes) / 1024 / 1024
          total_used_space,
       fragments.total_tbs_free_bytes / 1024 / 1024
          total_tablespace_free_space,
       ( ( (files.total_tbs_bytes - fragments.total_tbs_free_bytes)
          / files.total_tbs_bytes)
        * 100)
          total_used_pct,
       ( (fragments.total_tbs_free_bytes / files.total_tbs_bytes) * 100)
          total_free_pct,
       AUTOEXTEND.total_growth_tbs / 1024 / 1024 max_size_of_tablespace,
       ( ( (AUTOEXTEND.total_growth_tbs
            - (AUTOEXTEND.total_growth_tbs - fragments.total_tbs_free_bytes))
          / AUTOEXTEND.total_growth_tbs)
        * 100)
          total_auto_used_pct,
       ( ( (AUTOEXTEND.total_growth_tbs - fragments.total_tbs_free_bytes)
          / AUTOEXTEND.total_growth_tbs)
        * 100)
          total_auto_free_pct
  FROM dba_tablespaces a,
       files,
       fragments,
       AUTOEXTEND,
       tbs_auto
 WHERE     a.tablespace_name = files.tablespace_name
       AND a.tablespace_name = fragments.tablespace_name
       AND a.tablespace_name = AUTOEXTEND.tablespace_name
       AND a.tablespace_name = tbs_auto.tablespace_name(+);

Yararlı olması Dilegiyle…
Yazar : Mustafa Bektaş Tepe

926 total views, no views today


  • Sertifikasyon



  • Etiketler

  • Topluluklar

                     
                     
  • Live Traffic Feed

    Feedjit Widget
  • Copyright © 1996-2010 Mustafa Bektaş Tepe. All rights reserved.
    Türkçeleştirme Blogizma | AltyapıWordPress
    Takip Et

    Her yeni yazı için posta kutunuza gönderim alın.

    Diğer takipçilere katılın: