import os import fdb import csv,time,pandas as pd import openpyxl PathToSaveCSV=r"z:\Dropbox\Ordinace\Reporty" timestr = time.strftime("%Y-%m-%d %H-%M-%S ") CSVname="Pacienti.xlsx" # PathToSaveCSV=r"//tower/tempspeed" con = fdb.connect( host='192.168.1.10', database=r'm:\MEDICUS\data\medicus.FDB', user='sysdba', password='masterkey',charset='WIN1250') #Server=192.168.1.10 #Path=M:\Medicus\Data\Medicus.fdb # Create a Cursor object that operates in the context of Connection con: cur = con.cursor() # import openpyxl module import openpyxl import xlwings as xw wb = openpyxl.Workbook() sheet = wb.active # wb.save("sample.xlsx") #Načtení očkování registrovaných pacientů cur.execute("select rodcis,prijmeni,jmeno,ockzaz.datum,kodmz,ockzaz.poznamka,latka,nazev,expire from registr join kar on registr.idpac=kar.idpac join ockzaz on registr.idpac=ockzaz.idpac where datum_zruseni is null and kar.vyrazen!='A' and kar.rodcis is not null and idicp!=0 order by ockzaz.datum desc") nacteno=cur.fetchall() print(len(nacteno)) sheet.title="Očkování" sheet.append(["Rodne cislo","Prijmeni","Jmeno","Datum ockovani","Kod MZ","Sarze","Latka","Nazev","Expirace"]) #nacteno jsou ockovani for row in nacteno: sheet.append(row) wb.save(os.path.join(PathToSaveCSV ,timestr+CSVname)) #Načtení registrovaných pacientů cur.execute("select rodcis,prijmeni,jmeno,datum_registrace,registr.idpac,poj from registr join kar on registr.idpac=kar.idpac where kar.vyrazen!='A' and kar.rodcis is not null and idicp!=0 and datum_zruseni is null") nacteno=cur.fetchall() print(len(nacteno)) wb.create_sheet('Registrovani',0) sheet=wb['Registrovani'] sheet.append(["Rodne cislo","Prijmeni","Jmeno","Datum registrace","ID pacienta","Pojistovna"]) #nacteno jsou registrovani for row in nacteno: sheet.append(row) wb.save(os.path.join(PathToSaveCSV ,timestr+CSVname)) #Načtení receptů cur.execute("""select kar.rodcis, TRIM(kar.prijmeni) ||' '|| substring(kar.jmeno from 1 for 1) ||'.' as jmeno, recept.datum, TRIM(recept.lek) ||' '|| trim(recept.dop) as lek, recept.expori AS Poc, CASE WHEN recept.opakovani is null THEN 1 ELSE recept.opakovani END AS OP, recept.uhrada, recept.dsig, recept.NOTIFIKACE_KONTAKT as notifikace, recept_epodani.erp, recept_epodani.vystavitel_jmeno, recept.atc, recept.CENAPOJ, recept.cenapac from recept LEFT Join RECEPT_EPODANI on recept.id_epodani=recept_epodani.id LEFT join kar on recept.idpac=kar.idpac order by datum desc,erp desc""" ) nacteno=cur.fetchall() print(len(nacteno)) wb.create_sheet('Recepty',0) sheet=wb['Recepty'] sheet.title="Recepty" sheet.append(["Rodné číslo","Jméno","Datum vystavení","Název leku","Poč.","Op.","Úhr.","Da signa","Notifikace","eRECEPT","Vystavil","ATC","Cena pojišťovna","Cena pacient"]) #nacteno jsou ockovani for row in nacteno: try: sheet.append(row) except: continue wb.save(os.path.join(PathToSaveCSV ,timestr+CSVname)) #Načtení vykony vsech cur.execute("select dokladd.rodcis,TRIM(prijmeni) ||', '|| TRIM(jmeno),dokladd.datose,dokladd.kod,dokladd.pocvyk,dokladd.ddgn,dokladd.body,vykony.naz " "from kar join dokladd on kar.rodcis=dokladd.rodcis join vykony on dokladd.kod=vykony.kod where (datose>=vykony.platiod and datose<=vykony.platido) OR (datose>=vykony.platiod and vykony.platido is null) order by dokladd.datose desc,dokladd.rodcis") wb.create_sheet('Vykony',0) sheet=wb['Vykony'] nacteno=cur.fetchall() print(len(nacteno)) sheet.append(["Rodne cislo","Jmeno","Datum vykonu","Kod","Pocet","Dg.","Body","Nazev"]) #nacteno jsou ockovani for row in nacteno: sheet.append(row) wb.save(os.path.join(PathToSaveCSV ,timestr+CSVname)) #Načtení neschopenek import datetime def pocet_dni(zacnes,konnes,pracne): dnes=datetime.date.today() if pracne=='A': return (dnes-zacnes).days if pracne=='N' and zacnes is not None and konnes is not None and zacnes<=konnes: return (konnes-zacnes).days else: return "NA" cur.execute("select nes.idpac, " "kar.rodcis, " "TRIM(prijmeni) ||', '|| TRIM(jmeno), " "nes.datnes, " "nes.ecn, " "nes.zacnes, " "nes.pracne, " "nes.konnes, " "nes.diagno, " "nes.kondia, " "nes.updated " "from nes " "left join kar on nes.idpac=kar.idpac where nes.datnes<=current_date " "order by datnes desc") tmpnacteno_vse=[] nacteno_vse=cur.fetchall() cur.execute("select nes.idpac, " "kar.rodcis, " "TRIM(prijmeni) ||', '|| TRIM(jmeno), " "nes.datnes, " "nes.ecn, " "nes.zacnes, " "nes.pracne, " "nes.konnes, " "nes.diagno, " "nes.kondia, " "nes.updated " "from nes " "left join kar on nes.idpac=kar.idpac where nes.datnes<=current_date and pracne='A'" "order by datnes desc") tmpnacteno_aktivni=[] nacteno_aktivni=cur.fetchall() for row in nacteno_vse: tmpnacteno_vse.append((row[0],row[1],row[2],row[3],row[4],row[5],row[6],row[7],pocet_dni(row[5],row[7],row[6]),row[8],row[9],row[10])) for row in nacteno_aktivni: (tmpnacteno_aktivni.append((row[0],row[1],row[2],row[3],row[4],row[5],row[6],row[7],pocet_dni(row[5],row[7],row[6]),row[8],row[9],row[10]))) wb.create_sheet('Neschopenky všechny',0) sheet=wb["Neschopenky všechny"] sheet.append(["ID pac","Rodne cislo","Jmeno","Datum neschopenky","Číslo neschopenky","Zacatek","Aktivní?","Konec","Pocet dni","Diagnoza zacatel","Diagnoza konec","Aktualizovano"]) for row in tmpnacteno_vse: sheet.append(row) wb.create_sheet('Neschopenky aktivní',0) sheet=wb["Neschopenky aktivní"] sheet.append(["ID pac","Rodne cislo","Jmeno","Datum neschopenky","Číslo neschopenky","Zacatek","Aktivní?","Konec","Pocet dni","Diagnoza zacatel","Diagnoza konec","Aktualizovano"]) for row in tmpnacteno_aktivni: sheet.append(row) #Načtení preventivni prohlidky cur.execute("select all dokladd.rodcis,TRIM(prijmeni) ||', '|| TRIM(jmeno),dokladd.datose,dokladd.kod,vykony.naz,dokladd.ddgn,dokladd.body " "from dokladd left join kar on dokladd.rodcis=kar.rodcis join vykony on dokladd.kod=vykony.kod where " "((datose>=vykony.platiod and datose<=vykony.platido) OR (datose>=vykony.platiod and vykony.platido is null)) and (dokladd.kod=1022 or dokladd.kod=1021) " "order by datose desc") wb.create_sheet('Preventivni prohlidky',0) sheet=wb['Preventivni prohlidky'] nacteno=cur.fetchall() print(len(nacteno)) sheet.append(["Rodne cislo","Jmeno","Datum","Kod","Název","Dg.","Body"]) for row in nacteno: sheet.append(row) wb.save(os.path.join(PathToSaveCSV ,timestr+CSVname)) #Nacteni INR cur.execute("select all dokladd.rodcis,TRIM(prijmeni) ||', '|| TRIM(jmeno),dokladd.datose,dokladd.kod,vykony.naz,dokladd.ddgn,dokladd.body " "from dokladd left join kar on dokladd.rodcis=kar.rodcis join vykony on dokladd.kod=vykony.kod where " "((datose>=vykony.platiod and datose<=vykony.platido) OR (datose>=vykony.platiod and vykony.platido is null)) and (dokladd.kod=01443) " "order by datose desc") wb.create_sheet('INR',0) sheet=wb['INR'] nacteno=cur.fetchall() print(len(nacteno)) sheet.append(["Rodne cislo","Jmeno","Datum","Kod","Název","Dg.","Body"]) for row in nacteno: sheet.append(row) wb.save(os.path.join(PathToSaveCSV ,timestr+CSVname)) #Nacteni CRP cur.execute("select all dokladd.rodcis,TRIM(prijmeni) ||', '|| TRIM(jmeno),dokladd.datose,dokladd.kod,vykony.naz,dokladd.ddgn,dokladd.body " "from dokladd left join kar on dokladd.rodcis=kar.rodcis join vykony on dokladd.kod=vykony.kod where " "((datose>=vykony.platiod and datose<=vykony.platido) OR (datose>=vykony.platiod and vykony.platido is null)) and (dokladd.kod=02230 or dokladd.kod=09111) " "order by datose desc,dokladd.rodcis,dokladd.kod") wb.create_sheet('CRP',0) sheet=wb['CRP'] nacteno=cur.fetchall() print(len(nacteno)) sheet.append(["Rodne cislo","Jmeno","Datum","Kod","Název","Dg.","Body"]) for row in nacteno: sheet.append(row) wb.save(os.path.join(PathToSaveCSV ,timestr+CSVname)) #Nacteni Holter cur.execute("select all dokladd.rodcis,TRIM(prijmeni) ||', '|| TRIM(jmeno),dokladd.datose,dokladd.kod,vykony.naz,dokladd.ddgn,dokladd.body " "from dokladd left join kar on dokladd.rodcis=kar.rodcis join vykony on dokladd.kod=vykony.kod where " "((datose>=vykony.platiod and datose<=vykony.platido) OR (datose>=vykony.platiod and vykony.platido is null)) and (dokladd.kod=17129) " "order by datose desc,dokladd.rodcis,dokladd.kod") wb.create_sheet('Holter',0) sheet=wb['Holter'] nacteno=cur.fetchall() print(len(nacteno)) sheet.append(["Rodne cislo","Jmeno","Datum","Kod","Název","Dg.","Body"]) for row in nacteno: sheet.append(row) wb.save(os.path.join(PathToSaveCSV ,timestr+CSVname)) #Nacteni prostata cur.execute("select all dokladd.rodcis,TRIM(prijmeni) ||', '|| TRIM(jmeno),dokladd.datose,dokladd.kod,vykony.naz,dokladd.ddgn,dokladd.body " "from dokladd left join kar on dokladd.rodcis=kar.rodcis join vykony on dokladd.kod=vykony.kod where " "((datose>=vykony.platiod and datose<=vykony.platido) OR (datose>=vykony.platiod and vykony.platido is null)) and (dokladd.kod=01130 or dokladd.kod=01131 or dokladd.kod=01132 or dokladd.kod=01133 or dokladd.kod=01134) " "order by datose desc,dokladd.rodcis,dokladd.kod") wb.create_sheet('Prostata',0) sheet=wb['Prostata'] nacteno=cur.fetchall() print(len(nacteno)) sheet.append(["Rodne cislo","Jmeno","Datum","Kod","Název","Dg.","Body"]) for row in nacteno: sheet.append(row) wb.save(os.path.join(PathToSaveCSV ,timestr+CSVname)) #Nacteni TOKS cur.execute("select all dokladd.rodcis,TRIM(prijmeni) ||', '|| TRIM(jmeno),dokladd.datose,dokladd.kod,vykony.naz,dokladd.ddgn,dokladd.body " "from dokladd left join kar on dokladd.rodcis=kar.rodcis join vykony on dokladd.kod=vykony.kod where " "((datose>=vykony.platiod and datose<=vykony.platido) OR (datose>=vykony.platiod and vykony.platido is null)) and " "(dokladd.kod=15118 or dokladd.kod=15119 or dokladd.kod=15120 or dokladd.kod=15121) " "order by datose desc,dokladd.rodcis,dokladd.kod") wb.create_sheet('TOKS',0) sheet=wb['TOKS'] nacteno=cur.fetchall() print(len(nacteno)) sheet.append(["Rodne cislo","Jmeno","Datum","Kod","Název","Dg.","Body"]) for row in nacteno: sheet.append(row) wb.save(os.path.join(PathToSaveCSV ,timestr+CSVname)) #Nacteni COVID cur.execute("select all dokladd.rodcis,TRIM(prijmeni) ||', '|| TRIM(jmeno),dokladd.datose,dokladd.kod,vykony.naz,dokladd.ddgn,dokladd.body " "from dokladd left join kar on dokladd.rodcis=kar.rodcis join vykony on dokladd.kod=vykony.kod where " "((datose>=vykony.platiod and datose<=vykony.platido) OR (datose>=vykony.platiod and vykony.platido is null)) and " "(dokladd.kod=01306) " "order by datose desc,dokladd.rodcis,dokladd.kod") wb.create_sheet('COVID',0) sheet=wb['COVID'] nacteno=cur.fetchall() print(len(nacteno)) sheet.append(["Rodne cislo","Jmeno","Datum","Kod","Název","Dg.","Body"]) for row in nacteno: sheet.append(row) wb.save(os.path.join(PathToSaveCSV ,timestr+CSVname)) #Nacteni Streptest cur.execute("select all dokladd.rodcis,TRIM(prijmeni) ||', '|| TRIM(jmeno),dokladd.datose,dokladd.kod,vykony.naz,dokladd.ddgn,dokladd.body " "from dokladd left join kar on dokladd.rodcis=kar.rodcis join vykony on dokladd.kod=vykony.kod where " "((datose>=vykony.platiod and datose<=vykony.platido) OR (datose>=vykony.platiod and vykony.platido is null)) and " "(dokladd.kod=02220) " "order by datose desc,dokladd.rodcis,dokladd.kod") wb.create_sheet('Streptest',0) sheet=wb['Streptest'] nacteno=cur.fetchall() print(len(nacteno)) sheet.append(["Rodne cislo","Jmeno","Datum","Kod","Název","Dg.","Body"]) for row in nacteno: sheet.append(row) # autofilter for ws in wb.worksheets: # Get the maximum number of rows and columns max_row = ws.max_row max_column = ws.max_column ws.auto_filter.ref = f"A1:{openpyxl.utils.get_column_letter(max_column)}{max_row}" # ws.auto_filter.ref = ws.dimensions wb.save(os.path.join(PathToSaveCSV ,timestr+CSVname)) # Tento modul je pouze na autofit jednotlivych sloupcu na vsech listech workbooku file = os.path.join(PathToSaveCSV ,timestr+CSVname) with xw.App(visible=False) as app: wb = xw.Book(file) for sheet in range(len(wb.sheets)): ws = wb.sheets[sheet] ws.autofit() # centrování receptů sheet = wb.sheets['Recepty'] for sloupec in ["C:C", "E:E", "F:F", "G:G", "I:I", "M:M", "N:N"]: sheet.range(sloupec).api.HorizontalAlignment = 3 # 3 = Center wb.save() wb.close()