Files
ytp/docs/DATABASE.md
2025-11-03 23:12:45 +03:00

438 lines
13 KiB
Markdown
Raw Blame History

This file contains ambiguous Unicode characters
This file contains Unicode characters that might be confused with other characters. If you think that this is intentional, you can safely ignore this warning. Use the Escape button to reveal them.
# Veritabanı Şema Dokümantasyonu
Yakıt Takip Sistemi veritabanı yapısı, tablolar, ilişkiler ve veri modeli hakkında kapsamlı bilgi.
## 📋 İçerik
- [Genel Bakış](#genel-bakış)
- [Tablolar](#tablolar)
- [İlişkiler](#ilişkiler)
- [Veri Modeli](#veri-modeli)
- [Index'ler](#indexler)
- [Örnek Veriler](#örnek-veriler)
- [Migration](#migration)
## 🗄️ Genel Bakış
### Veritabanı Türü
- **Motor**: SQLite 3
- **Dosya**: `data/app.db`
- **Encoding**: UTF-8
- **Foreign Keys**: Aktif
### Tasarım İlkeleri
- Normalizasyon: 3NF
- Veri bütünlüğü: Foreign key constraints
- Audit trail: created_at timestamp'ları
- Atomic operations: Transaction destek
## 📊 Tablolar
### users
Sistem kullanıcılarını ve rollerini tutar.
```sql
CREATE TABLE users (
id INTEGER PRIMARY KEY AUTOINCREMENT,
username TEXT UNIQUE NOT NULL,
password TEXT NOT NULL,
role TEXT NOT NULL CHECK(role IN ('admin','fuel_manager','inventory_manager')),
display_name TEXT NOT NULL,
created_at TEXT DEFAULT CURRENT_TIMESTAMP
);
```
| Kolon | Tip | Kısıtlar | Açıklama |
|-------|-----|----------|----------|
| id | INTEGER | PRIMARY KEY, AUTOINCREMENT | Benzersiz kullanıcı ID |
| username | TEXT | UNIQUE, NOT NULL | Kullanıcı adı |
| password | TEXT | NOT NULL | Şifre (hash'lenmemiş) |
| role | TEXT | NOT NULL, CHECK | Kullanıcı rolü |
| display_name | TEXT | NOT NULL | Görünen ad |
| created_at | TEXT | DEFAULT CURRENT_TIMESTAMP | Kayıt tarihi |
### vehicles
Araç bilgilerini tutar.
```sql
CREATE TABLE vehicles (
id INTEGER PRIMARY KEY AUTOINCREMENT,
brand TEXT NOT NULL,
model TEXT NOT NULL,
year INTEGER NOT NULL,
plate TEXT UNIQUE NOT NULL,
created_at TEXT DEFAULT CURRENT_TIMESTAMP
);
```
| Kolon | Tip | Kısıtlar | Açıklama |
|-------|-----|----------|----------|
| id | INTEGER | PRIMARY KEY, AUTOINCREMENT | Benzersiz araç ID |
| brand | TEXT | NOT NULL | Marka |
| model | TEXT | NOT NULL | Model |
| year | INTEGER | NOT NULL | Model yılı |
| plate | TEXT | UNIQUE, NOT NULL | Plaka |
| created_at | TEXT | DEFAULT CURRENT_TIMESTAMP | Kayıt tarihi |
### units
Askeri birlik bilgilerini tutar.
```sql
CREATE TABLE units (
id INTEGER PRIMARY KEY AUTOINCREMENT,
name TEXT UNIQUE NOT NULL,
address TEXT NOT NULL,
stk TEXT NOT NULL,
btk TEXT NOT NULL,
contact_name TEXT NOT NULL,
contact_rank TEXT NOT NULL,
contact_registry TEXT NOT NULL,
contact_identity TEXT NOT NULL,
contact_phone TEXT NOT NULL,
created_at TEXT DEFAULT CURRENT_TIMESTAMP
);
```
| Kolon | Tip | Kısıtlar | Açıklama |
|-------|-----|----------|----------|
| id | INTEGER | PRIMARY KEY, AUTOINCREMENT | Benzersiz birlik ID |
| name | TEXT | UNIQUE, NOT NULL | Birlik adı |
| address | TEXT | NOT NULL | Adres |
| stk | TEXT | NOT NULL | STK kodu |
| btk | TEXT | NOT NULL | BTK kodu |
| contact_name | TEXT | NOT NULL | Sorumlu kişi adı |
| contact_rank | TEXT | NOT NULL | Rütbe |
| contact_registry | TEXT | NOT NULL | Sicil no |
| contact_identity | TEXT | NOT NULL | TC kimlik no |
| contact_phone | TEXT | NOT NULL | Telefon |
| created_at | TEXT | DEFAULT CURRENT_TIMESTAMP | Kayıt tarihi |
### fuel_personnel
Yakıt personeli bilgilerini tutar.
```sql
CREATE TABLE fuel_personnel (
id INTEGER PRIMARY KEY AUTOINCREMENT,
full_name TEXT NOT NULL,
rank TEXT NOT NULL,
registry_number TEXT UNIQUE NOT NULL,
identity_number TEXT NOT NULL,
phone TEXT NOT NULL,
created_at TEXT DEFAULT CURRENT_TIMESTAMP
);
```
| Kolon | Tip | Kısıtlar | Açıklama |
|-------|-----|----------|----------|
| id | INTEGER | PRIMARY KEY, AUTOINCREMENT | Benzersiz personel ID |
| full_name | TEXT | NOT NULL | Tam ad |
| rank | TEXT | NOT NULL | Rütbe |
| registry_number | TEXT | UNIQUE, NOT NULL | Sicil numarası |
| identity_number | TEXT | NOT NULL | TC kimlik no |
| phone | TEXT | NOT NULL | Telefon |
| created_at | TEXT | DEFAULT CURRENT_TIMESTAMP | Kayıt tarihi |
### fuel_slips
Yakıt ikmal fişlerini tutar.
```sql
CREATE TABLE fuel_slips (
id INTEGER PRIMARY KEY AUTOINCREMENT,
slip_number INTEGER UNIQUE,
created_at TEXT DEFAULT CURRENT_TIMESTAMP,
slip_date TEXT NOT NULL,
force TEXT NOT NULL,
unit_id INTEGER NOT NULL,
unit_name TEXT NOT NULL,
vehicle_id INTEGER NOT NULL,
vehicle_description TEXT NOT NULL,
plate TEXT NOT NULL,
fuel_amount_number REAL NOT NULL,
fuel_amount_text TEXT NOT NULL,
fuel_type TEXT NOT NULL,
receiver_id INTEGER NOT NULL,
receiver_name TEXT NOT NULL,
receiver_rank TEXT NOT NULL,
receiver_registry TEXT NOT NULL,
receiver_phone TEXT NOT NULL,
giver_id INTEGER NOT NULL,
giver_name TEXT NOT NULL,
giver_rank TEXT NOT NULL,
giver_registry TEXT NOT NULL,
giver_phone TEXT NOT NULL,
notes TEXT,
inventory_manager_id INTEGER NOT NULL,
fuel_manager_id INTEGER NOT NULL,
status TEXT DEFAULT 'pending',
rejection_reason TEXT,
FOREIGN KEY (unit_id) REFERENCES units(id),
FOREIGN KEY (vehicle_id) REFERENCES vehicles(id),
FOREIGN KEY (receiver_id) REFERENCES fuel_personnel(id),
FOREIGN KEY (giver_id) REFERENCES fuel_personnel(id),
FOREIGN KEY (inventory_manager_id) REFERENCES users(id),
FOREIGN KEY (fuel_manager_id) REFERENCES users(id)
);
```
| Kolon | Tip | Kısıtlar | Açıklama |
|-------|-----|----------|----------|
| id | INTEGER | PRIMARY KEY, AUTOINCREMENT | Benzersiz fiş ID |
| slip_number | INTEGER | UNIQUE | Fiş seri numarası |
| created_at | TEXT | DEFAULT CURRENT_TIMESTAMP | Oluşturma tarihi |
| slip_date | TEXT | NOT NULL | Fiş tarihi |
| force | TEXT | NOT NULL | Kuvvet (MSB, KKK, etc.) |
| unit_id | INTEGER | FOREIGN KEY, NOT NULL | Birlik ID |
| unit_name | TEXT | NOT NULL | Birlik adı (redunant) |
| vehicle_id | INTEGER | FOREIGN KEY, NOT NULL | Araç ID |
| vehicle_description | TEXT | NOT NULL | Araç açıklaması |
| plate | TEXT | NOT NULL | Plaka |
| fuel_amount_number | REAL | NOT NULL | Yakıt miktarı (rakam) |
| fuel_amount_text | TEXT | NOT NULL | Yakıt miktarı (yazı) |
| fuel_type | TEXT | NOT NULL | Yakıt türü |
| receiver_id | INTEGER | FOREIGN KEY, NOT NULL | Teslim alan ID |
| receiver_name | TEXT | NOT NULL | Teslim alan adı |
| receiver_rank | TEXT | NOT NULL | Teslim alan rütbesi |
| receiver_registry | TEXT | NOT NULL | Teslim alan sicili |
| receiver_phone | TEXT | NOT NULL | Teslim alan telefonu |
| giver_id | INTEGER | FOREIGN KEY, NOT NULL | Teslim eden ID |
| giver_name | TEXT | NOT NULL | Teslim eden adı |
| giver_rank | TEXT | NOT NULL | Teslim eden rütbesi |
| giver_registry | TEXT | NOT NULL | Teslim eden sicili |
| giver_phone | TEXT | NOT NULL | Teslim eden telefonu |
| notes | TEXT | NULL | Notlar |
| inventory_manager_id | INTEGER | FOREIGN KEY, NOT NULL | Mal sorumlusu ID |
| fuel_manager_id | INTEGER | FOREIGN KEY, NOT NULL | Yakıt sorumlusu ID |
| status | TEXT | DEFAULT 'pending' | Durum (pending/approved/rejected) |
| rejection_reason | TEXT | NULL | Red gerekçesi |
## 🔗 İlişkiler
### Entity Relationship Diagram
```
users (1) -----> (0..n) fuel_slips (fuel_manager_id)
users (1) -----> (0..n) fuel_slips (inventory_manager_id)
users (1) -----> (0..n) users (admin creates)
units (1) -----> (0..n) fuel_slips (unit_id)
vehicles (1) -----> (0..n) fuel_slips (vehicle_id)
fuel_personnel (1) -----> (0..n) fuel_slips (receiver_id)
fuel_personnel (1) -----> (0..n) fuel_slips (giver_id)
```
### Relationship Types
- **One-to-Many**: users → fuel_slips (hem fuel_manager_id hem de inventory_manager_id)
- **One-to-Many**: units → fuel_slips
- **One-to-Many**: vehicles → fuel_slips
- **One-to-Many**: fuel_personnel → fuel_slips (hem receiver_id hem de giver_id)
## 📈 Veri Modeli
### Status Flow (fuel_slips.status)
```
pending → approved
rejected
```
### Role Hierarchy
```
admin (süper kullanıcı)
├── fuel_manager (fiş oluşturabilir)
└── inventory_manager (fiş onaylayabilir)
```
### Kuvvet Listesi (Enum)
```sql
-- Geçerli kuvvet değerleri
'MSB', 'K.K.K.', 'Dz.K.K.', 'Hv.K.K.', 'SGK', 'Gnkur. Bşk.', 'Hrt.Gn.K.'
```
### Yakıt Türleri (Örnek)
```sql
-- Örnek yakıt türleri
'Benzin', 'Motorin', 'Benzin-95', 'Motorin-10', 'LPG'
```
## 🗂️ Index'ler
### Otomatik Index'ler
- `PRIMARY KEY` → Her tabloda otomatik oluşturulur
- `UNIQUE` → Belirtilen kolonlarda otomatik oluşturulur
### Önerilen Manuel Index'ler
```sql
-- Performans için önerilen index'ler
CREATE INDEX idx_fuel_slips_status ON fuel_slips(status);
CREATE INDEX idx_fuel_slips_date ON fuel_slips(slip_date);
CREATE INDEX idx_fuel_slips_inventory_manager ON fuel_slips(inventory_manager_id);
CREATE INDEX idx_fuel_slips_fuel_manager ON fuel_slips(fuel_manager_id);
CREATE INDEX idx_vehicles_plate ON vehicles(plate);
CREATE INDEX idx_units_name ON units(name);
CREATE INDEX idx_users_role ON users(role);
```
## 📝 Örnek Veriler
### users Tablosu
```sql
INSERT INTO users (username, password, role, display_name) VALUES
('admin', 'Admin!123', 'admin', 'Istasyon Admini'),
('yakitsorum', 'Yakit@123', 'fuel_manager', 'Yakit Sorumlusu'),
('malsorum1', 'Mal@123', 'inventory_manager', 'Mal Sorumlusu 1');
```
### vehicles Tablosu
```sql
INSERT INTO vehicles (brand, model, year, plate) VALUES
('Ford', 'Transit', 2021, '34 AYT 312'),
('Isuzu', 'NPR', 2019, '34 FZT 908');
```
### units Tablosu
```sql
INSERT INTO units (
name, address, stk, btk, contact_name, contact_rank,
contact_registry, contact_identity, contact_phone
) VALUES
(
'Merkez Birlik',
'Cumhuriyet Mah. İstasyon Cad. No:12/1 İstanbul',
'STK-4589',
'BTK-9021',
'Yzb. Murat Kaya',
'Yuzbasi',
'MK4587',
'25478963210',
'+90 532 456 78 12'
);
```
### fuel_personnel Tablosu
```sql
INSERT INTO fuel_personnel (
full_name, rank, registry_number, identity_number, phone
) VALUES
(
'Astsb. Cahit Demir',
'Astsubay',
'CD5561',
'14523698741',
'+90 532 223 45 67'
),
(
'Sv. Uzm. Er Ali Korkmaz',
'Sozlesmeli Er',
'AK7812',
'32987456100',
'+90 555 893 22 10'
);
```
### fuel_slips Tablosu
```sql
INSERT INTO fuel_slips (
slip_number, slip_date, force, unit_id, unit_name,
vehicle_id, vehicle_description, plate,
fuel_amount_number, fuel_amount_text, fuel_type,
receiver_id, receiver_name, receiver_rank, receiver_registry, receiver_phone,
giver_id, giver_name, giver_rank, giver_registry, giver_phone,
inventory_manager_id, fuel_manager_id
) VALUES
(
1, '2024-01-01', 'MSB', 1, 'Merkez Birlik',
1, 'Ford Transit', '34 AYT 312',
50, 'Elli', 'Benzin',
1, 'Astsb. Cahit Demir', 'Astsubay', 'CD5561', '+90 532 223 45 67',
2, 'Sv. Uzm. Er Ali Korkmaz', 'Sozlesmeli Er', 'AK7812', '+90 555 893 22 10',
3, 2
);
```
## 🔄 Migration
### Sürüm Geçmişi
#### v1.0.0 - İlk Sürüm
- users, vehicles, units, fuel_personnel, fuel_slips tabloları oluşturuldu
- Temel foreign key ilişkileri kuruldu
- Örnek veriler eklendi
#### v1.1.0 - Status Eklendi
- `fuel_slips` tablosuna `status` kolonu eklendi
- `fuel_slips` tablosuna `rejection_reason` kolonu eklendi
- Mevcut kayıtlar için 'pending' olarak varsayılan değer atandı
### Migration Script'i
```sql
-- v1.1.0 Migration
ALTER TABLE fuel_slips ADD COLUMN status TEXT DEFAULT 'pending';
ALTER TABLE fuel_slips ADD COLUMN rejection_reason TEXT;
-- Örnek index'ler
CREATE INDEX IF NOT EXISTS idx_fuel_slips_status ON fuel_slips(status);
CREATE INDEX IF NOT EXISTS idx_fuel_slips_date ON fuel_slips(slip_date);
CREATE INDEX IF NOT EXISTS idx_fuel_slips_inventory_manager ON fuel_slips(inventory_manager_id);
```
### Veritabanı Yedekleme
```bash
# SQLite yedekleme
sqlite3 data/app.db ".backup data/app_backup_$(date +%Y%m%d_%H%M%S).db"
# Veri dışa aktarma
sqlite3 data/app.db ".dump" > data/app_export_$(date +%Y%m%d_%H%M%S).sql
# Veri içe aktarma
sqlite3 data/app.db < data/app_export_20240101_120000.sql
```
## 🔍 Veri Sorguları
### Yaygın Sorgular
#### Aktif Kullanıcılar
```sql
SELECT role, COUNT(*) as count FROM users GROUP BY role;
```
#### Aylık Yakıt İstatistikleri
```sql
SELECT
strftime('%Y-%m', slip_date) as month,
COUNT(*) as slip_count,
SUM(fuel_amount_number) as total_fuel
FROM fuel_slips
WHERE status = 'approved'
GROUP BY strftime('%Y-%m', slip_date)
ORDER BY month DESC;
```
#### Birlik Bazında İstatistikler
```sql
SELECT
u.name,
COUNT(fs.id) as slip_count,
SUM(fs.fuel_amount_number) as total_fuel
FROM units u
LEFT JOIN fuel_slips fs ON u.id = fs.unit_id AND fs.status = 'approved'
GROUP BY u.id, u.name
ORDER BY slip_count DESC;
```
#### Personel Aktivitesi
```sql
SELECT
fp.full_name,
fp.rank,
COUNT(CASE WHEN fs.id IS NOT NULL THEN 1 END) as slips_involved
FROM fuel_personnel fp
LEFT JOIN fuel_slips fs ON fp.id = fs.receiver_id OR fp.id = fs.giver_id
GROUP BY fp.id, fp.full_name, fp.rank
ORDER BY slips_involved DESC;
```
---
**Not**: Veritabanı yapısı geliştirme sürecinde değişebilir. Migration geçmişini takip etmek önemlidir.