Create a gist now

Instantly share code, notes, and snippets.

What would you like to do?
SQL Script to Create OpmFedScope Database
CREATE DATABASE [OpmFedScope]
CONTAINMENT = NONE
ON PRIMARY
( NAME = N'OpmFedScope', FILENAME = N'C:\Program Files\Microsoft SQL Server\MSSQL12.MSSQLSERVER\MSSQL\DATA\OpmFedScope.mdf' , SIZE = 134144KB , MAXSIZE = UNLIMITED, FILEGROWTH = 1024KB )
LOG ON
( NAME = N'OpmFedScope_log', FILENAME = N'C:\Program Files\Microsoft SQL Server\MSSQL12.MSSQLSERVER\MSSQL\DATA\OpmFedScope_log.ldf' , SIZE = 15040KB , MAXSIZE = 2048GB , FILEGROWTH = 10%)
GO
ALTER DATABASE [OpmFedScope] SET COMPATIBILITY_LEVEL = 120
GO
IF (1 = FULLTEXTSERVICEPROPERTY('IsFullTextInstalled'))
begin
EXEC [OpmFedScope].[dbo].[sp_fulltext_database] @action = 'enable'
end
GO
ALTER DATABASE [OpmFedScope] SET ANSI_NULL_DEFAULT OFF
GO
ALTER DATABASE [OpmFedScope] SET ANSI_NULLS OFF
GO
ALTER DATABASE [OpmFedScope] SET ANSI_PADDING OFF
GO
ALTER DATABASE [OpmFedScope] SET ANSI_WARNINGS OFF
GO
ALTER DATABASE [OpmFedScope] SET ARITHABORT OFF
GO
ALTER DATABASE [OpmFedScope] SET AUTO_CLOSE OFF
GO
ALTER DATABASE [OpmFedScope] SET AUTO_SHRINK OFF
GO
ALTER DATABASE [OpmFedScope] SET AUTO_UPDATE_STATISTICS ON
GO
ALTER DATABASE [OpmFedScope] SET CURSOR_CLOSE_ON_COMMIT OFF
GO
ALTER DATABASE [OpmFedScope] SET CURSOR_DEFAULT GLOBAL
GO
ALTER DATABASE [OpmFedScope] SET CONCAT_NULL_YIELDS_NULL OFF
GO
ALTER DATABASE [OpmFedScope] SET NUMERIC_ROUNDABORT OFF
GO
ALTER DATABASE [OpmFedScope] SET QUOTED_IDENTIFIER OFF
GO
ALTER DATABASE [OpmFedScope] SET RECURSIVE_TRIGGERS OFF
GO
ALTER DATABASE [OpmFedScope] SET DISABLE_BROKER
GO
ALTER DATABASE [OpmFedScope] SET AUTO_UPDATE_STATISTICS_ASYNC OFF
GO
ALTER DATABASE [OpmFedScope] SET DATE_CORRELATION_OPTIMIZATION OFF
GO
ALTER DATABASE [OpmFedScope] SET TRUSTWORTHY OFF
GO
ALTER DATABASE [OpmFedScope] SET ALLOW_SNAPSHOT_ISOLATION OFF
GO
ALTER DATABASE [OpmFedScope] SET PARAMETERIZATION SIMPLE
GO
ALTER DATABASE [OpmFedScope] SET READ_COMMITTED_SNAPSHOT OFF
GO
ALTER DATABASE [OpmFedScope] SET HONOR_BROKER_PRIORITY OFF
GO
ALTER DATABASE [OpmFedScope] SET RECOVERY SIMPLE
GO
ALTER DATABASE [OpmFedScope] SET MULTI_USER
GO
ALTER DATABASE [OpmFedScope] SET PAGE_VERIFY CHECKSUM
GO
ALTER DATABASE [OpmFedScope] SET DB_CHAINING OFF
GO
ALTER DATABASE [OpmFedScope] SET FILESTREAM( NON_TRANSACTED_ACCESS = OFF )
GO
ALTER DATABASE [OpmFedScope] SET TARGET_RECOVERY_TIME = 0 SECONDS
GO
ALTER DATABASE [OpmFedScope] SET DELAYED_DURABILITY = DISABLED
GO
EXEC sys.sp_db_vardecimal_storage_format N'OpmFedScope', N'ON'
GO
USE [OpmFedScope]
GO
/****** Object: Table [dbo].[DTagelvl] Script Date: 9/8/2016 2:04:15 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
SET ANSI_PADDING ON
GO
CREATE TABLE [dbo].[DTagelvl](
[AGELVL] [char](1) NULL,
[AGELVLT] [varchar](20) NULL
) ON [PRIMARY]
GO
SET ANSI_PADDING OFF
GO
/****** Object: Table [dbo].[DTagy] Script Date: 9/8/2016 2:04:15 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
SET ANSI_PADDING ON
GO
CREATE TABLE [dbo].[DTagy](
[AGYTYP] [char](1) NULL,
[AGYTYPT] [varchar](60) NULL,
[AGY] [char](2) NULL,
[AGYT] [varchar](100) NULL,
[AGYSUB] [char](4) NULL,
[AGYSUBT] [varchar](100) NULL,
[AGYTshort] [varchar](100) NULL
) ON [PRIMARY]
GO
SET ANSI_PADDING OFF
GO
/****** Object: Table [dbo].[DTedlvl] Script Date: 9/8/2016 2:04:15 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
SET ANSI_PADDING ON
GO
CREATE TABLE [dbo].[DTedlvl](
[EDLVLTYP] [tinyint] NULL,
[EDLVLTYPT] [varchar](40) NULL,
[EDLVL] [char](2) NULL,
[EDLVLT] [varchar](100) NULL,
[EDLVLTYPTshort] [varchar](40) NULL
) ON [PRIMARY]
GO
SET ANSI_PADDING OFF
GO
/****** Object: Table [dbo].[DTloc] Script Date: 9/8/2016 2:04:15 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
SET ANSI_PADDING ON
GO
CREATE TABLE [dbo].[DTloc](
[LOCTYP] [tinyint] NULL,
[LOCTYPT] [varchar](30) NULL,
[LOC] [char](2) NULL,
[LOCT] [varchar](40) NULL,
[LOCTshort] [varchar](40) NULL
) ON [PRIMARY]
GO
SET ANSI_PADDING OFF
GO
/****** Object: Table [dbo].[DTloslvl] Script Date: 9/8/2016 2:04:15 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
SET ANSI_PADDING ON
GO
CREATE TABLE [dbo].[DTloslvl](
[LOSLVL] [char](1) NULL,
[LOSLVLT] [varchar](30) NULL
) ON [PRIMARY]
GO
SET ANSI_PADDING OFF
GO
/****** Object: Table [dbo].[DTocc] Script Date: 9/8/2016 2:04:15 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
SET ANSI_PADDING ON
GO
CREATE TABLE [dbo].[DTocc](
[OCCTYP] [tinyint] NULL,
[OCCTYPT] [varchar](15) NULL,
[OCCFAM] [char](2) NULL,
[OCCFAMT] [varchar](50) NULL,
[OCC] [char](4) NULL,
[OCCT] [varchar](100) NULL,
[OCCTshort] [varchar](100) NULL
) ON [PRIMARY]
GO
SET ANSI_PADDING OFF
GO
/****** Object: Table [dbo].[DTpatco] Script Date: 9/8/2016 2:04:15 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
SET ANSI_PADDING ON
GO
CREATE TABLE [dbo].[DTpatco](
[PATCO] [tinyint] NULL,
[PATCOT] [varchar](30) NULL
) ON [PRIMARY]
GO
SET ANSI_PADDING OFF
GO
/****** Object: Table [dbo].[DTppgrd] Script Date: 9/8/2016 2:04:15 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
SET ANSI_PADDING ON
GO
CREATE TABLE [dbo].[DTppgrd](
[PPTYP] [char](1) NULL,
[PPTYPT] [varchar](70) NULL,
[PPGROUP] [char](2) NULL,
[PPGROUPT] [varchar](50) NULL,
[PAYPLAN] [char](2) NULL,
[PAYPLANT] [varchar](120) NULL,
[PPGRD] [varchar](5) NULL
) ON [PRIMARY]
GO
SET ANSI_PADDING OFF
GO
/****** Object: Table [dbo].[DTsallvl] Script Date: 9/8/2016 2:04:15 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
SET ANSI_PADDING ON
GO
CREATE TABLE [dbo].[DTsallvl](
[SALLVL] [char](1) NULL,
[SALLVLT] [varchar](30) NULL
) ON [PRIMARY]
GO
SET ANSI_PADDING OFF
GO
/****** Object: Table [dbo].[DTstemocc] Script Date: 9/8/2016 2:04:15 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
SET ANSI_PADDING ON
GO
CREATE TABLE [dbo].[DTstemocc](
[STEMAGG] [char](1) NULL,
[STEMAGGT] [varchar](50) NULL,
[STEMTYP] [char](2) NULL,
[STEMTYPT] [varchar](50) NULL,
[STEMOCC] [char](4) NULL,
[STEMOCCT] [varchar](200) NULL
) ON [PRIMARY]
GO
SET ANSI_PADDING OFF
GO
/****** Object: Table [dbo].[DTsuper] Script Date: 9/8/2016 2:04:15 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
SET ANSI_PADDING ON
GO
CREATE TABLE [dbo].[DTsuper](
[SUPERTYP] [char](1) NULL,
[SUPERTYPT] [varchar](20) NULL,
[SUPERVIS] [char](1) NULL,
[SUPERVIST] [varchar](50) NULL
) ON [PRIMARY]
GO
SET ANSI_PADDING OFF
GO
/****** Object: Table [dbo].[DTtoa] Script Date: 9/8/2016 2:04:15 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
SET ANSI_PADDING ON
GO
CREATE TABLE [dbo].[DTtoa](
[TOATYP] [char](1) NULL,
[TOATYPT] [varchar](20) NULL,
[TOA] [char](2) NULL,
[TOAT] [varchar](50) NULL
) ON [PRIMARY]
GO
SET ANSI_PADDING OFF
GO
/****** Object: Table [dbo].[FACTDATA] Script Date: 9/8/2016 2:04:15 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
SET ANSI_PADDING ON
GO
CREATE TABLE [dbo].[FACTDATA](
[AGYSUB] [char](4) NULL,
[LOC] [char](2) NULL,
[AGELVL] [char](1) NULL,
[EDLVL] [char](2) NULL,
[GSEGRD] [char](2) NULL,
[LOSLVL] [char](1) NULL,
[OCC] [char](4) NULL,
[PATCO] [char](1) NULL,
[PPGRD] [varchar](5) NULL,
[SALLVL] [char](1) NULL,
[STEMOCC] [char](4) NULL,
[SUPERVIS] [char](1) NULL,
[TOA] [char](2) NULL,
[WORKSCH] [char](1) NULL,
[WORKSTAT] [char](1) NULL,
[DATECODE] [char](6) NULL,
[EMPLOYMENT] [bit] NULL,
[SALARY] [int] NULL,
[LOS] [numeric](5, 2) NULL
) ON [PRIMARY]
GO
SET ANSI_PADDING OFF
GO
USE [master]
GO
ALTER DATABASE [OpmFedScope] SET READ_WRITE
GO
-- sample query of the OpmFedScope database
select
f.AGYSUB AgencyCode
,ag.AGYTshort AgencyName
,f.LOC LocationCode
,l.LOCTshort LocationName
,f.AGELVL AgeCode
,a.AGELVLT AgeRange
,ed.EDLVLTYPTshort EducationLevel
,f.LOS LengthOfService
,los.LOSLVLT ServiceRange
,oc.OCCTshort
,f.PPGRD PayGrade
,sal.SALLVLT SalaryRange
,f.SALARY Salary
from
dbo.FACTDATA f
left join dbo.DTagy ag on (f.AGYSUB = ag.AGYSUB)
left join dbo.DTloc l on (f.LOC = l.LOC)
left join dbo.DTagelvl a on (f.AGELVL = a.AGELVL)
left join dbo.DTedlvl ed on (f.EDLVL = ed.EDLVL)
left join dbo.DTloslvl los on (f.LOSLVL = los.LOSLVL)
left join dbo.DTocc oc on (f.OCC = oc.OCC)
left join dbo.DTpatco p on (f.PATCO = p.PATCO)
left join dbo.DTppgrd gr on (f.PPGRD = gr.PPGRD)
left join dbo.DTsallvl sal on (f.SALLVL = sal.SALLVL)
left join dbo.DTstemocc stm on (f.STEMOCC = stm.STEMOCC)
left join dbo.DTsuper sup on (f.SUPERVIS = sup.SUPERVIS)