Daniel Quathamer
1 year ago
4 changed files with 153 additions and 1 deletions
@ -0,0 +1,13 @@ |
|||||||
|
Im SuperX/BI-Modul SOS Version 1.2 (ca. 2019) gab es einen Bug, der zu Duplikaten bei Hauptprüfungen führte, wenn die Stichtagsdaten der Prüfungen eingefroren waren. |
||||||
|
|
||||||
|
Sie finden solche Duplikate, indem Sie das SQL-Script |
||||||
|
duplikate_in_sos_lab_stg_finden.sql |
||||||
|
ausführen. Wenn Sie hier Datensätze finden: |
||||||
|
|
||||||
|
Das vorliegende Script für PostgreSQL (nicht Informix) dient zum Bereinigen der Prüfungen in der Faktentabelle `sos_lab_stg`. Es entfernt Duplikate in den eingefrorenen Datenbeständen. |
||||||
|
|
||||||
|
*Wichtig*: Vor dem Lauf sichern Sie die Tabelle `sos_lab_stg` |
||||||
|
|
||||||
|
Zum Start richten Sie die Shellscripte ein und starten das Script mit einen SQL-Client Ihrer Wahl, oder in den SuperX-Shellscripten mit |
||||||
|
|
||||||
|
DOSQL duplikate_in_sos_lab_stg_korrigieren.sql |
@ -0,0 +1,11 @@ |
|||||||
|
select sem_der_pruefung,labnr,sourcesystem into temp tmp_doppelt |
||||||
|
from sos_lab_stg where abschnitt=2 |
||||||
|
and stichtag=(select tid from sos_stichtag where appl_key='4') |
||||||
|
group by 1,2,3 |
||||||
|
having count(*) > 1 |
||||||
|
order by 1; |
||||||
|
|
||||||
|
select sem_der_pruefung,count(*) from tmp_doppelt group by 1; |
||||||
|
|
||||||
|
drop table tmp_doppelt; |
||||||
|
|
@ -0,0 +1,128 @@ |
|||||||
|
|
||||||
|
--wichtig: vor dem Lauf die Tabelle sos_lab_stg sichern. |
||||||
|
|
||||||
|
SELECT |
||||||
|
now(), |
||||||
|
'Vorher Anzahl Sätze in sos_lab_stg:'::CHAR(50), |
||||||
|
count(*) |
||||||
|
FROM sos_lab_stg |
||||||
|
GROUP BY 1,2; |
||||||
|
|
||||||
|
begin work; |
||||||
|
|
||||||
|
create table sos_lab_stg_dopp ( |
||||||
|
matrikel_nr INT, |
||||||
|
studiengang_nr SMALLINT, |
||||||
|
fach_nr SMALLINT, |
||||||
|
d_geburt DATE, |
||||||
|
geschlecht SMALLINT, |
||||||
|
ca12_staat SMALLINT, |
||||||
|
sem_der_pruefung SMALLINT, |
||||||
|
sem_d_abg_pruefung SMALLINT, |
||||||
|
ch30_fach CHAR(10), |
||||||
|
ch39_vertief CHAR(10), |
||||||
|
ch35_ang_abschluss CHAR(10), |
||||||
|
kz_fach CHAR(10), |
||||||
|
tid_stg INT, |
||||||
|
lehr CHAR(10), |
||||||
|
d_abg_pruefung DATE, |
||||||
|
parstg_anf DATE, |
||||||
|
parstg_ende DATE, |
||||||
|
note DECIMAL(3,2), |
||||||
|
abschnitt SMALLINT, |
||||||
|
fach_sem_zahl DECIMAL(10,2), |
||||||
|
regel SMALLINT, |
||||||
|
hzbart SMALLINT, |
||||||
|
stort CHAR(10), |
||||||
|
sem_ein INT, |
||||||
|
stufrm CHAR(10), |
||||||
|
pversion SMALLINT, |
||||||
|
schwerpunkt CHAR(10), |
||||||
|
pstatus CHAR(10), |
||||||
|
stichtag INT, |
||||||
|
summe INT, |
||||||
|
pordnr INT, |
||||||
|
pnr INT, |
||||||
|
pvermerk CHAR(10), |
||||||
|
part CHAR(10), |
||||||
|
labnr INT, |
||||||
|
schriftlich SMALLINT, |
||||||
|
prueck SMALLINT, |
||||||
|
zeitabschnitt CHAR(10), |
||||||
|
pform CHAR(10), |
||||||
|
pversuch INT, |
||||||
|
pseudonym VARCHAR(255), |
||||||
|
ch35_ang_abschluss_stg CHAR(10), |
||||||
|
ch30_fach_stg CHAR(10), |
||||||
|
ch39_vertief_stg CHAR(10), |
||||||
|
schwerpunkt_stg CHAR(10), |
||||||
|
kz_fach_stg CHAR(10), |
||||||
|
pversion_stg INT, |
||||||
|
sourcesystem INT, |
||||||
|
malus FLOAT, |
||||||
|
bonus FLOAT, |
||||||
|
sem_overall SMALLINT, |
||||||
|
sem_practice SMALLINT, |
||||||
|
sem_abroad SMALLINT, |
||||||
|
sem_former_degree_program SMALLINT, |
||||||
|
type_of_doctorate_astat INT, |
||||||
|
stuart CHAR(10), |
||||||
|
pruefungsamt_nr CHAR(7), |
||||||
|
ppunkte FLOAT, |
||||||
|
stutyp CHAR(10) |
||||||
|
); |
||||||
|
|
||||||
|
insert into sos_lab_stg_dopp |
||||||
|
SELECT distinct * |
||||||
|
FROM sos_lab_stg where sem_der_pruefung < (SELECT apnr FROM konstanten WHERE beschreibung='SOS_start_lab') |
||||||
|
and stichtag = (select I.tid from sos_stichtag I where I.appl_key='4'); |
||||||
|
|
||||||
|
|
||||||
|
|
||||||
|
select sem_der_pruefung,stichtag,labnr,sourcesystem, matrikel_nr into tmp tmp_doppelt |
||||||
|
from sos_lab_stg |
||||||
|
where sem_der_pruefung < (SELECT apnr FROM konstanten WHERE beschreibung='SOS_start_lab') |
||||||
|
and stichtag = (select I.tid from sos_stichtag I where I.appl_key='4') |
||||||
|
and abschnitt=2 |
||||||
|
group by 1,2,3,4,5 |
||||||
|
having count(*)>1 |
||||||
|
; |
||||||
|
|
||||||
|
|
||||||
|
update sos_lab_stg_dopp set stutyp=null where sem_der_pruefung < (SELECT apnr FROM konstanten WHERE beschreibung='SOS_start_lab') |
||||||
|
and stichtag = (select I.tid from sos_stichtag I where I.appl_key='4') |
||||||
|
and labnr in (select labnr from tmp_doppelt); |
||||||
|
update sos_lab_stg_dopp set stuart=null where sem_der_pruefung < (SELECT apnr FROM konstanten WHERE beschreibung='SOS_start_lab') |
||||||
|
and stichtag = (select I.tid from sos_stichtag I where I.appl_key='4') |
||||||
|
and labnr in (select labnr from tmp_doppelt); |
||||||
|
update sos_lab_stg_dopp set stufrm=null where sem_der_pruefung < (SELECT apnr FROM konstanten WHERE beschreibung='SOS_start_lab') |
||||||
|
and stichtag = (select I.tid from sos_stichtag I where I.appl_key='4') |
||||||
|
and labnr in (select labnr from tmp_doppelt); |
||||||
|
|
||||||
|
delete from sos_lab_stg where sem_der_pruefung < (SELECT apnr FROM konstanten WHERE beschreibung='SOS_start_lab') |
||||||
|
and stichtag = (select I.tid from sos_stichtag I where I.appl_key='4'); |
||||||
|
|
||||||
|
insert into sos_lab_stg (matrikel_nr,studiengang_nr,fach_nr,d_geburt,geschlecht,ca12_staat,sem_der_pruefung,sem_d_abg_pruefung,ch30_fach,ch39_vertief,ch35_ang_abschluss, |
||||||
|
kz_fach,tid_stg,lehr,d_abg_pruefung,parstg_anf,parstg_ende,note,abschnitt,fach_sem_zahl,regel,hzbart,stort,sem_ein,stufrm,pversion,schwerpunkt,pstatus,stichtag,summe,pordnr, |
||||||
|
pnr,pvermerk,part,labnr,schriftlich,prueck,zeitabschnitt,pform,pversuch,pseudonym,ch35_ang_abschluss_stg,ch30_fach_stg,ch39_vertief_stg,schwerpunkt_stg,kz_fach_stg,pversion_stg, |
||||||
|
sourcesystem,malus,bonus,sem_overall,sem_practice,sem_abroad,sem_former_degree_program,type_of_doctorate_astat,stuart,pruefungsamt_nr,ppunkte,stutyp) |
||||||
|
SELECT distinct matrikel_nr,studiengang_nr,fach_nr,d_geburt,geschlecht,ca12_staat,sem_der_pruefung,sem_d_abg_pruefung,ch30_fach,ch39_vertief,ch35_ang_abschluss,kz_fach,min(tid_stg), |
||||||
|
lehr,d_abg_pruefung,parstg_anf,parstg_ende,note,abschnitt,max(fach_sem_zahl),regel,min(hzbart),stort,sem_ein,stufrm,pversion,schwerpunkt,pstatus,stichtag,summe,pordnr,pnr,pvermerk, |
||||||
|
part,labnr,schriftlich,prueck,zeitabschnitt,pform,pversuch,pseudonym,ch35_ang_abschluss_stg,ch30_fach_stg,ch39_vertief_stg,schwerpunkt_stg,kz_fach_stg,pversion_stg,sourcesystem, |
||||||
|
malus,bonus,sem_overall,sem_practice,sem_abroad,sem_former_degree_program,type_of_doctorate_astat,stuart,pruefungsamt_nr,ppunkte,stutyp |
||||||
|
FROM sos_lab_stg_dopp where sem_der_pruefung < (SELECT apnr FROM konstanten WHERE beschreibung='SOS_start_lab') |
||||||
|
and stichtag = (select I.tid from sos_stichtag I where I.appl_key='4') |
||||||
|
group by 1,2,3,4,5,6,7,8,9,10,11,12,14,15,16,17,18,19,21,23,24,25,26,27,28,29,30,31,32,33,34,35,36,37,38,39,40,41,42,43,44,45,46,47,48,49,50,51,52,53,54,55,56,57,58,59; |
||||||
|
|
||||||
|
drop table sos_lab_stg_dopp; |
||||||
|
drop table tmp_doppelt; |
||||||
|
|
||||||
|
commit; |
||||||
|
|
||||||
|
|
||||||
|
SELECT |
||||||
|
now(), |
||||||
|
'Nachher Anzahl Sätze in sos_lab_stg:'::CHAR(50), |
||||||
|
count(*) |
||||||
|
FROM sos_lab_stg |
||||||
|
GROUP BY 1,2; |
Loading…
Reference in new issue