360 lines
11 KiB
Plaintext
360 lines
11 KiB
Plaintext
#ifdef MS_SQL
|
|
-- This entire script must be run as user FCLT_EN, *not* as SA
|
|
-- When you restore a database on a differenct machine you may
|
|
-- not be able to log on as FCLT_EN. Run the following once as
|
|
-- user SA to solve that
|
|
-- sp_change_users_login 'Auto_fix', 'FCLT_EN'
|
|
#endif
|
|
--
|
|
-- Update script van Facilitor versie 4.44 naar 4.45
|
|
--
|
|
/*
|
|
* This script is precompiled so #if(n)def MS_SQL can be used to distinguish between
|
|
* SQL Server and Oracle specific statements.
|
|
*
|
|
* C-style comment is removed from the result
|
|
*/
|
|
#include "modules.h"
|
|
#include "comsql.h"
|
|
#include "INS\inssql.h"
|
|
SET TERMOUT ON
|
|
SET FEEDBACK OFF
|
|
SET ECHO OFF
|
|
SET PAGESIZE 0
|
|
/*
|
|
* Test eerst of de vorige versie van module FAC zoals genoemd in tabel
|
|
* fac_module wel het te verwachten versienummer heeft
|
|
* als dat niet zo is dient de gebruiker het script ZELF af te breken middels
|
|
* control-c.
|
|
* Als dat wel zo is vervolgt het script en zal aan het einde van het script
|
|
* het interne versienummer en de datum worden bijgewerkt.
|
|
*/
|
|
/* !!BELANGRIJK!!
|
|
* Als er bij de upgrade een NIEUWE tabel of view wordt gecreeerd, moeten ook
|
|
* de daarvoor benodigde GRANTS en SYNONYMS worden geregeld!!!
|
|
* Dit doen we in de $..after.sql, die ook hier wordt gegenereerd.
|
|
*/
|
|
SPOOL OFF
|
|
SET HEADING OFF
|
|
CLEAR SCREEN
|
|
|
|
PROMPT ***********************************************************************
|
|
PROMPT
|
|
PROMPT UPGRADE SCRIPT van Facilitor versie 4.44 naar 4.45
|
|
#ifdef MS_SQL
|
|
PROMPT versie voor MS SQL Server
|
|
#else
|
|
PROMPT versie voor Oracle
|
|
#endif
|
|
PROMPT
|
|
SELECT 'De huidige versie van Facilitor zou moeten zijn 04.44 en is: '
|
|
|| fac_module_version
|
|
FROM fac_module
|
|
WHERE fac_module_name='FAC';
|
|
PROMPT
|
|
PROMPT Indien de huidige versie NIET de verwachte versie is mag dit script
|
|
PROMPT niet worden gerund! In dit geval dient het script nu middels
|
|
PROMPT CONTROL-C te worden afgebroken.
|
|
PROMPT
|
|
PROMPT Indien de versies overeenkomen dient nu ENTER te worden gedrukt...
|
|
PROMPT
|
|
PROMPT ***********************************************************************
|
|
ACCEPT nix PROMPT ''
|
|
PROMPT
|
|
PROMPT De upgrade wordt vervolgd. Even geduld a.u.b...
|
|
PROMPT
|
|
|
|
SET TERMOUT ON
|
|
SET HEADING OFF
|
|
SET FEEDBACK ON
|
|
SET ECHO ON
|
|
SET VERIFY OFF
|
|
SET LINESIZE 1000
|
|
SET SERVEROUTPUT ON;
|
|
|
|
SPOOL x444to445.LST
|
|
|
|
UPDATE_VERSION('04.45');
|
|
COMMIT;
|
|
|
|
/****************************** PLAATS HIERONDER DE UPDATES PER CALL ******************************/
|
|
|
|
#ifdef MS_SQL
|
|
#endif
|
|
|
|
#ifndef MS_SQL
|
|
#endif
|
|
|
|
/////////////////////////////////////////////////////////////////////////////////////////////////
|
|
-- AKZA#318 Koppelen meerdere afdelingen aan pz-ers
|
|
alter table prs_perslideenheid drop constraint prs_u_prs_perslideenheid_key;
|
|
alter table prs_perslideenheid add constraint prs_u_prs_perslideenheid_key unique (prs_perslid_key,prs_afdeling_key);
|
|
|
|
/////////////////////////////////////////////////////////////////////////////////////////////////
|
|
-- FSN#547 Gebruik van key ipv naam contactpersoon in MI Servicedesk
|
|
|
|
ALTER TABLE mld_opdr DISABLE ALL TRIGGERS;
|
|
|
|
UPDATE mld_opdr o
|
|
SET prs_perslid_key =
|
|
(SELECT prs_perslid_key
|
|
FROM PRS_V_PERSLID_FULLNAMES_ALL p
|
|
WHERE p.prs_perslid_naam_full = o.mld_opdr_contactpersoon)
|
|
WHERE prs_perslid_key IS NULL;
|
|
|
|
ALTER table mld_opdr ENABLE ALL TRIGGERS;
|
|
|
|
|
|
/////////////////////////////////////////////////////////////////////////////////////////////////
|
|
-- FSN#701 Toevoegen dummy veld en label veld bij flexibele kenmerken
|
|
|
|
-- MLD
|
|
ALTER TABLE mld_srtkenmerk DROP CONSTRAINT mld_c_mld_srtkenmerk_kenmtype;
|
|
ALTER TABLE mld_srtkenmerk ADD CONSTRAINT mld_c_mld_srtkenmerk_kenmtype CHECK(mld_srtkenmerk_kenmerktype IN ('C','N','D','R','X','L','Q'));
|
|
-- RES
|
|
ALTER TABLE res_srtkenmerk DROP CONSTRAINT res_c_res_srtkenmerk_kenmtype;
|
|
ALTER TABLE res_srtkenmerk ADD CONSTRAINT res_c_res_srtkenmerk_kenmtype CHECK(res_srtkenmerk_kenmerktype IN ('C','N','D','R','X','L','Q'));
|
|
-- CNT
|
|
ALTER TABLE cnt_srtkenmerk DROP CONSTRAINT cnt_c_cnt_srtkenmerk_kenmtype;
|
|
ALTER TABLE cnt_srtkenmerk ADD CONSTRAINT cnt_c_cnt_srtkenmerk_kenmtype CHECK(cnt_srtkenmerk_kenmerktype IN ('C','N','D','R','X','L','Q'));
|
|
-- INS
|
|
ALTER TABLE ins_srtkenmerk DROP CONSTRAINT ins_c_ins_srtkenmerk_kenmtype;
|
|
ALTER TABLE ins_srtkenmerk ADD CONSTRAINT ins_c_ins_srtkenmerk_kenmtype CHECK(ins_srtkenmerk_kenmerktype IN ('C','N','D','R','X','L','Q'));
|
|
-- ALG
|
|
ALTER TABLE alg_kenmerk DROP CONSTRAINT alg_c_alg_kenmerk_type;
|
|
ALTER TABLE alg_kenmerk ADD CONSTRAINT alg_c_alg_kenmerk_type CHECK(alg_kenmerk_kenmerktype IS NOT NULL AND alg_kenmerk_kenmerktype IN ('C','N','D','R','X','L','Q'));
|
|
-- Onderstaande statement voor de volledigheid opgenomen, kan redundant zijn (in dit geval ORA negeren: ORA-02443: Cannot drop constraint - nonexistent constraint).
|
|
ALTER TABLE alg_kenmerk DROP CONSTRAINT ALG_C_ALG_KENMERK_TYPE2;
|
|
-- PRS
|
|
ALTER TABLE prs_kenmerk DROP CONSTRAINT prs_c_prs_kenmerk_type2;
|
|
ALTER TABLE prs_kenmerk ADD CONSTRAINT prs_c_prs_kenmerk_type2 CHECK(prs_kenmerk_kenmerktype IS NOT NULL and prs_kenmerk_kenmerktype IN ('C','N','D','R','X','L','Q'));
|
|
|
|
/////////////////////////////////////////////////////////////////////////////////////////////////
|
|
|
|
-- FSN #766
|
|
|
|
DROP SEQUENCE res_s_res_cyclus;
|
|
CREATE SEQUENCE res_s_res_cyclus MINVALUE 20;
|
|
|
|
/////////////////////////////////////////////////////////////////////////////////////////////////
|
|
// Insert van WEB_TERMAN kan foutmelding opleveren als deze functie
|
|
// reeds eerder is toegevoegd (is echter niet bij alle klanten gebeurd
|
|
// vandaar deze insert nogmaals is opgenomen.
|
|
-- FSN #994
|
|
|
|
DEF_FAC_FUNCTIE('WEB_TERMAN', 'Graphics:Terreinbeheer', 'CAD', 0, 0,'');
|
|
|
|
|
|
-- CONN#122
|
|
DEF_FAC_FUNCTIE('WEB_OBJUSE', 'Backoffice:Objectverbruik', 'INS', 15, 1,'Om objectverbruik te registreren');
|
|
|
|
|
|
-- CONN#121
|
|
/* NOTE: this is a redefinition of this macro,to support updating with the same sources; it assumes all functions are present already */
|
|
#define DEF_FAC_FUNCTIE(c, o, m, l, d, i) UPDATE fac_functie SET fac_functie_omschrijving=o,fac_functie_module=m, fac_functie_min_level=l, fac_functie_discipline=d, fac_functie_info=i WHERE fac_functie_code=c
|
|
|
|
DEF_FAC_FUNCTIE('WEB_PHONEB', 'Business:Telefoonboek', 'PRS', 13, 0,'Om zelf de gegevens van medewerkers op te kunnen zoeken');
|
|
|
|
|
|
-- CONN#172
|
|
ALTER TABLE INS_SRTDEEL MODIFY (INS_SRTDEEL_EENHEID VARCHAR2(30));
|
|
|
|
|
|
/////////////////////////////////////////////////////////////////////////////////////////////////
|
|
/////////////////////////////////////////////////////////////////////////////////////////////////GENERIC PART
|
|
/////////////////////////////////////////////////////////////////////////////////////////////////
|
|
|
|
#define CREATE_VIEW(view_name, level) \
|
|
CREATE OR REPLACE VIEW view_name
|
|
|
|
|
|
// Recreation all views
|
|
|
|
#include "..\..\sql\fac\fac_vie.src"
|
|
#include "..\..\sql\alg\alg_vie.src"
|
|
#include "..\..\sql\ins\ins_vie.src"
|
|
#include "..\..\sql\prs\prs_vie1.src"
|
|
#include "..\..\sql\prs\prs_pac.src"
|
|
#include "..\..\sql\prs\prs_vie2.src"
|
|
#include "..\..\sql\mld\mld_vie.src"
|
|
#include "..\..\sql\cad\cad_vie1.src"
|
|
#include "..\..\sql\res\res_vie.src"
|
|
#include "..\..\sql\bez\bez_vie.src"
|
|
#include "..\..\sql\web\web_vie.src"
|
|
#include "..\..\sql\cnt\cnt_vie.src"
|
|
#include "..\..\sql\bes\bes_vie.src"
|
|
#include "..\..\sql\pra\pra_vie.src"
|
|
|
|
COMMIT;
|
|
|
|
// Recreation all packages
|
|
|
|
#include "..\..\sql\cnt\cnt_pac.src"
|
|
#include "..\..\sql\mld\mld_pac.src"
|
|
#include "..\..\sql\fac\fac_pac.src"
|
|
#include "..\..\sql\ins\ins_pac.src"
|
|
#include "..\..\sql\cad\cad_pac.src"
|
|
#include "..\..\sql\res\res_pac.src"
|
|
#include "..\..\sql\bez\bez_pac.src"
|
|
#include "..\..\sql\web\web_pac.src"
|
|
#include "..\..\sql\bes\bes_pac.src"
|
|
#include "..\..\sql\pra\pra_pac.src"
|
|
COMMIT;
|
|
|
|
// Views that uses packages
|
|
#include "..\..\sql\cad\cad_vie2.src"
|
|
#include "..\..\sql\mld\mld_vie2.src"
|
|
|
|
|
|
// Recreation all triggers
|
|
|
|
#include "..\..\sql\fac\fac_tri.src"
|
|
#include "..\..\sql\alg\alg_tri.src"
|
|
#include "..\..\sql\ins\ins_tri.src"
|
|
#include "..\..\sql\prs\prs_tri.src"
|
|
#include "..\..\sql\cnt\cnt_tri.src"
|
|
#include "..\..\sql\mld\mld_tri.src"
|
|
#include "..\..\sql\cad\cad_tri.src"
|
|
#include "..\..\sql\res\res_tri.src"
|
|
#include "..\..\sql\bez\bez_tri.src"
|
|
#include "..\..\sql\web\web_tri.src"
|
|
#include "..\..\sql\bes\bes_tri.src"
|
|
#include "..\..\sql\pra\pra_tri.src"
|
|
|
|
COMMIT;
|
|
|
|
|
|
#ifdef MS_SQL
|
|
[skip]
|
|
-- EXTRA MSSQL
|
|
IF EXISTS(SELECT 1
|
|
FROM INFORMATION_SCHEMA.routines
|
|
WHERE routine_NAME LIKE 'make_views'
|
|
and routine_schema like user)
|
|
drop procedure make_views
|
|
go
|
|
|
|
create procedure make_views as
|
|
begin
|
|
DECLARE query CURSOR FOR
|
|
select distinct p.fac_package_name, o2.name
|
|
from sysobjects o1, fac_package p, sysobjects o2, sysdepends d
|
|
where
|
|
(o1.type = 'FN' or o1.type = 'P')
|
|
and o1.uid = user_id(p.fac_package_name)
|
|
and d.id = o1.id
|
|
and d.depid = o2.id
|
|
and (o2.type = 'U' or o2.type = 'V')
|
|
and not exists(select 1
|
|
from sysobjects o3
|
|
where uid = user_id(p.fac_package_name)
|
|
and o3.name=o2.name)
|
|
order by 1
|
|
|
|
declare @pk varchar(500);
|
|
declare @vw varchar(500);
|
|
declare @sql varchar(500);
|
|
|
|
OPEN query;
|
|
FETCH NEXT FROM query INTO @pk,@vw;
|
|
WHILE (@@FETCH_STATUS <> -1 ) BEGIN
|
|
set @sql = 'create view '+@pk+'.'+@vw
|
|
+ ' as select * from '+user+'.'+@vw;
|
|
exec(@sql);
|
|
FETCH NEXT FROM query INTO @pk,@vw;
|
|
END;
|
|
CLOSE query;
|
|
DEALLOCATE query;
|
|
end
|
|
go
|
|
|
|
IF EXISTS(SELECT 1
|
|
FROM INFORMATION_SCHEMA.routines
|
|
WHERE routine_NAME LIKE 'drop_views'
|
|
and routine_schema like user)
|
|
drop procedure drop_views
|
|
go
|
|
|
|
create procedure drop_views as
|
|
begin
|
|
DECLARE query CURSOR FOR
|
|
select distinct p.fac_package_name, o2.name
|
|
from sysobjects o1, fac_package p, sysobjects o2, sysdepends d
|
|
where
|
|
(o1.type = 'FN' or o1.type = 'P')
|
|
and o1.uid = user_id(p.fac_package_name)
|
|
and d.id = o1.id
|
|
and d.depid = o2.id
|
|
and (o2.type = 'U' or o2.type = 'V')
|
|
order by 1
|
|
|
|
declare @pk varchar(500);
|
|
declare @vw varchar(500);
|
|
declare @sql varchar(500);
|
|
|
|
OPEN query;
|
|
FETCH NEXT FROM query INTO @pk,@vw;
|
|
WHILE (@@FETCH_STATUS <> -1 ) BEGIN
|
|
set @sql = 'drop view '+@pk+'.'+@vw;
|
|
exec(@sql);
|
|
FETCH NEXT FROM query INTO @pk,@vw;
|
|
END;
|
|
CLOSE query;
|
|
DEALLOCATE query;
|
|
end
|
|
go
|
|
|
|
create procedure drop_old_views as
|
|
begin
|
|
DECLARE query CURSOR FOR
|
|
select p.fac_package_name,o.table_name
|
|
from fac_package p,information_schema.tables o
|
|
where o.table_schema=user
|
|
and exists(select 1
|
|
from information_schema.tables o2
|
|
where o2.table_schema like p.fac_package_name
|
|
and o2.table_name=o.table_name);
|
|
declare @pk varchar(500);
|
|
declare @vw varchar(500);
|
|
declare @sql varchar(500);
|
|
OPEN query;
|
|
FETCH NEXT FROM query INTO @pk,@vw;
|
|
WHILE (@@FETCH_STATUS <> -1 ) BEGIN
|
|
set @sql = 'drop view '+@pk+'.'+@vw
|
|
exec(@sql);
|
|
FETCH NEXT FROM query INTO @pk,@vw;
|
|
END;
|
|
CLOSE query;
|
|
DEALLOCATE query;
|
|
END
|
|
go
|
|
EXEC drop_old_views
|
|
go
|
|
DROP PROCEDURE drop_old_views
|
|
GO
|
|
UPDATE FAC_GEBRUIKER SET FAC_GEBRUIKER_USERNAME = 'FCLT_EN' WHERE FAC_GEBRUIKER_USERNAME = 'RWON';
|
|
GO
|
|
[/skip]
|
|
#endif
|
|
|
|
[skip]
|
|
#ifdef MS_SQL
|
|
EXEC drop_views
|
|
GO
|
|
EXEC make_views
|
|
GO
|
|
#endif
|
|
[/skip]
|
|
|
|
UPDATE FAC_MESSAGE
|
|
SET FAC_MESSAGE_TEXT = 'Facilitor 4.44.0'
|
|
WHERE FAC_MESSAGE_CODE = 'FAC_M002';
|
|
|
|
UPDATE FAC_MESSAGE
|
|
SET FAC_MESSAGE_TEXT = 'Welkom bij Facilitor 4.44.0'
|
|
WHERE FAC_MESSAGE_CODE = 'FAC_M035';
|
|
|
|
COMMIT;
|
|
SET ECHO OFF
|
|
PROMPT De upgrade is gereed.. Controleer de LST-files.
|
|
99 |