Pages

Thursday, October 31, 2019

Oracle Space Stats sql

COL tablespace_name FOR A30
COL owner FOR A30
COL segment_name FOR A30
COL USED_MB FOR 9999999999999
SET LINESIZE 140
SET PAGESIZE 200
COL tablespace_name FOR A30
COL file_name FOR A60
COL Mb FOR 9999999999999
COL MAX_MB FOR 9999999999999

spool tbs.txt

SELECT TABLESPACE_NAME, 
  (MAX(MAX_SPACE)-MAX(USED_SPACE)  )AS DBA_FREE_SPACE_MB,                                   
  MAX(USED_SPACE) AS USED_SPACE_MB, 
  MAX(MAX_SPACE) AS MAX_SPACE_MB, 
  ROUND(( (MAX(MAX_SPACE)-MAX(USED_SPACE)  ) /MAX(MAX_SPACE) ) *100) as FREE_PCT, 
  CASE WHEN (ROUND(( (MAX(MAX_SPACE)-MAX(USED_SPACE)  ) /MAX(MAX_SPACE) ) *100)<15)  THEN 'Y' ELSE 'N' END AS ADD_MORE_SPACE 
FROM ( 
SELECT tablespace_name,  
   ROUND(SUM(bytes)/1024/2014) AS FREE_SPACE, 
   0 AS MAX_SPACE, 
   0 AS USED_SPACE   
 FROM DBA_FREE_SPACE
 WHERE 1=1
   --AND tablespace_name LIKE '%IGT%' OR tablespace_name LIKE '%DWH%' OR tablespace_name LIKE '%REPORTS%' OR tablespace_name = 'SYSTEM'  OR tablespace_name = 'SYSAUX' 
 GROUP BY tablespace_name  
 UNION ALL 
 SELECT tablespace_name, 
   0 AS FREE_SPACE, 
   ROUND( SUM(CASE WHEN (bytes>maxbytes)  THEN bytes ELSE maxbytes END)/1024/1024) AS MAX_SPACE, 
     0 AS USED_SPACE 
 FROM DBA_DATA_FILES
  WHERE 1=1
   --AND tablespace_name LIKE '%IGT%' OR tablespace_name LIKE '%DWH%' OR tablespace_name LIKE '%REPORTS%' OR tablespace_name = 'SYSTEM'  OR tablespace_name = 'SYSAUX' 
 GROUP BY tablespace_name 
 UNION ALL 
 SELECT tablespace_name, 
     0 AS FREE_SPACE, 
     0 AS MAX_SPACE, 
     ROUND(SUM(bytes/1024/1024)) AS USED_SPACE 
  FROM DBA_SEGMENTS
 WHERE 1=1
   --AND tablespace_name LIKE '%IGT%' OR tablespace_name LIKE '%DWH%' OR tablespace_name LIKE '%REPORTS%' OR tablespace_name = 'SYSTEM'  OR tablespace_name = 'SYSAUX' 
GROUP BY tablespace_name 

GROUP BY tablespace_name;

spool off



spool segments.txt

SELECT owner, tablespace_name, segment_name, USED_MB 
   FROM ( 
  SELECT owner, tablespace_name, segment_name, ROUND(SUM(bytes)/1024/1024)AS USED_MB FROM DBA_SEGMENTS
   WHERE tablespace_name LIKE '%TABLE%' 
  GROUP BY owner, tablespace_name,segment_name 
  ORDER BY ROUND(SUM(bytes)/1024/1024) DESC 
) WHERE ROWNUM < 11;


SELECT owner, tablespace_name, segment_name, USED_MB 
   FROM ( 
  SELECT owner, tablespace_name, segment_name, ROUND(SUM(bytes)/1024/1024)AS USED_MB FROM DBA_SEGMENTS
   WHERE tablespace_name LIKE '%INDEX%' 
  GROUP BY owner, tablespace_name,segment_name 
  ORDER BY ROUND(SUM(bytes)/1024/1024) DESC 
) WHERE ROWNUM < 11;

SELECT owner, tablespace_name, segment_name, USED_MB 
   FROM ( 
  SELECT owner, tablespace_name, segment_name, ROUND(SUM(bytes)/1024/1024)AS USED_MB FROM DBA_SEGMENTS
   WHERE tablespace_name LIKE '%SYSTEM%' 
  GROUP BY owner, tablespace_name,segment_name 
  ORDER BY ROUND(SUM(bytes)/1024/1024) DESC 
) WHERE ROWNUM < 11;


SELECT owner, tablespace_name, segment_name, USED_MB 
   FROM ( 
  SELECT owner, tablespace_name, segment_name, ROUND(SUM(bytes)/1024/1024)AS USED_MB FROM DBA_SEGMENTS
   WHERE tablespace_name LIKE '%SYSAUX%' 
  GROUP BY owner, tablespace_name,segment_name 
  ORDER BY ROUND(SUM(bytes)/1024/1024) DESC 
) WHERE ROWNUM < 11;

spool off


spool datafile.txt
SELECT tablespace_name, file_name, ROUND(bytes/1024/1024) AS Mb, ROUND(maxbytes/1024/1024) AS MAX_MB
  FROM DBA_DATA_FILES;

spool off

Wednesday, October 30, 2019

Code example: String replacement in PL/SQL

CREATE OR REPLACE PACKAGE QA_UTIL AS
  PROCEDURE imsi_update;
END QA_UTIL;
/

CREATE OR REPLACE PACKAGE BODY QA_UTIL AS
-------------------------------------------
  PROCEDURE imsi_update AS

    CURSOR imsi_rows_cur IS
    SELECT QAT2_TESTS_RAN.*, rowid FROM QAT2_TESTS_RAN
     WHERE generalrange1 LIKE '% IMSI = %'
       AND generalrange1 NOT LIKE '% IMSI = ''%'
       AND test_name LIKE 'VFES%';


    v_generalrange      QAT2_TESTS.generalrange1%TYPE;
    v_generalrange_out  QAT2_TESTS.generalrange1%TYPE;
    v_part_1_ind        NUMBER;
    v_part_1            QAT2_TESTS.generalrange1%TYPE;

    v_part_imsi_ind     NUMBER;
    v_part_imsi         QAT2_TESTS.generalrange1%TYPE;

    v_part_2_ind        NUMBER;
    v_part_2         QAT2_TESTS.generalrange1%TYPE;

  BEGIN
    FOR imsi_rows_rec IN imsi_rows_cur LOOP
      --select * from DEBUG_IPN_W_EDR where IMSI = 214010000000010 and DESCRIPTION='GPRS' and ACTION_TYPE_NAME= 'RELAY' and ACTION_REASON_NAME='Sub: SubInact'
      v_generalrange := imsi_rows_rec.generalrange1;

      v_part_1_ind := INSTR(v_generalrange,'IMSI = ') + LENGTH ('IMSI = ')-1;
      v_part_1 := SUBSTR(v_generalrange,0,v_part_1_ind);

      v_part_imsi_ind := v_part_1_ind+1;
      v_part_imsi  := SUBSTR(v_generalrange,v_part_imsi_ind,LENGTH('214010000000010'));

      v_part_2_ind := v_part_imsi_ind + LENGTH('214010000000010');
      v_part_2 := SUBSTR(v_generalrange,v_part_2_ind);

      v_generalrange_out := v_part_1||''''||v_part_imsi||''''||v_part_2;

      UPDATE QAT2_TESTS_RAN 
         SET generalrange1 = v_generalrange_out 
       WHERE QAT2_TESTS_RAN.rowid = imsi_rows_rec.rowid;
      commit;

    END LOOP;

  EXCEPTION
    WHEN OTHERS THEN
      RAISE;
  END imsi_update;
-------------------------------------------
END QA_UTIL;
/

Thursday, October 24, 2019

SQLSERVER, change Database Isolation Level. Change database Collation. sp_change_users_login

==============================
Changing Database Isolation Level
==============================
How to resolve deadlock on Database level when changing Database Isolation Level

USE Jiratempdb
SELECT CASE transaction_isolation_level 
  WHEN 0 THEN 'Unspecified' 
  WHEN 1 THEN 'ReadUncommitted' 
  WHEN 2 THEN 'ReadCommitted' 
  WHEN 3 THEN 'Repeatable' 
  WHEN 4 THEN 'Serializable' 
  WHEN 5 THEN 'Snapshot' END AS TRANSACTION_ISOLATION_LEVEL 
  FROM sys.dm_exec_sessions 
where session_id = @@SPID

result: ReadCommitted
USE Jiratempdb
SELECT is_read_committed_snapshot_on 
  FROM sys.databases 
 WHERE name = 'Jiratempdb'
result = 0

In case of a deadlock error:

use master
go

EXEC sp_who2
SELECT * from sys.dm_exec_requests 
 WHERE command like 'ATRER%' 
ORDER BY command

kill <pid>



SET DEADLOCK_PRIORITY HIGH
GO

ALTER DATABASE XXX SET SINGLE_USER WITH ROLLBACK IMMEDIATE;
GO

ALTER DATABASE XXX set READ_COMMITTED_SNAPSHOT ON
GO

ALTER DATABASE XXX SET MULTI_USER
GO

USE Jiratempdb
SELECT is_read_committed_snapshot_on 
  FROM sys.databases 
 WHERE name = 'Jiratempdb'
result = 1



==============================
Changing Collation
==============================

USE master;  
GO

--Verify the collation setting.
SELECT name, collation_name  
FROM sys.databases  
WHERE name = N'jiradbdev';  
GO  
jiradbdev; SQL_Latin1_General_CP1_CI_AS

ALTER DATABASE XXX SET SINGLE_USER WITH ROLLBACK IMMEDIATE;
GO

ALTER DATABASE XXX COLLATE SQL_Latin1_General_CP437_CI_AI;
GO  

ALTER DATABASE XXX SET MULTI_USER
GO
  
--Verify the collation setting.  
SELECT name, collation_name  
FROM sys.databases  
WHERE name = N'jiradbdev';  
GO  
jiradbdev; SQL_Latin1_General_CP437_CI_AI

==============================
sp_change_users_login 'AUTO_FIX', 'my_user'
==============================
This command Maps database user to a SQL Server login.

It will be needed, if migrating database from InstanceA to InstanceB, via detach+attach, and using same user, which is a local user on InstanceA and on InstanceB.

Auto_Fix option -  Links a user entry in the sys.database_principals system catalog view in the current database to a SQL Server login of the same name. 

If a login with the same name does not exist, one will be created.