summaryrefslogtreecommitdiffstats
path: root/digikam/digikam/albumdb.cpp
blob: ef46b5ae239e868c432384e1e5f64321143d3622 (plain)
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
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
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
407
408
409
410
411
412
413
414
415
416
417
418
419
420
421
422
423
424
425
426
427
428
429
430
431
432
433
434
435
436
437
438
439
440
441
442
443
444
445
446
447
448
449
450
451
452
453
454
455
456
457
458
459
460
461
462
463
464
465
466
467
468
469
470
471
472
473
474
475
476
477
478
479
480
481
482
483
484
485
486
487
488
489
490
491
492
493
494
495
496
497
498
499
500
501
502
503
504
505
506
507
508
509
510
511
512
513
514
515
516
517
518
519
520
521
522
523
524
525
526
527
528
529
530
531
532
533
534
535
536
537
538
539
540
541
542
543
544
545
546
547
548
549
550
551
552
553
554
555
556
557
558
559
560
561
562
563
564
565
566
567
568
569
570
571
572
573
574
575
576
577
578
579
580
581
582
583
584
585
586
587
588
589
590
591
592
593
594
595
596
597
598
599
600
601
602
603
604
605
606
607
608
609
610
611
612
613
614
615
616
617
618
619
620
621
622
623
624
625
626
627
628
629
630
631
632
633
634
635
636
637
638
639
640
641
642
643
644
645
646
647
648
649
650
651
652
653
654
655
656
657
658
659
660
661
662
663
664
665
666
667
668
669
670
671
672
673
674
675
676
677
678
679
680
681
682
683
684
685
686
687
688
689
690
691
692
693
694
695
696
697
698
699
700
701
702
703
704
705
706
707
708
709
710
711
712
713
714
715
716
717
718
719
720
721
722
723
724
725
726
727
728
729
730
731
732
733
734
735
736
737
738
739
740
741
742
743
744
745
746
747
748
749
750
751
752
753
754
755
756
757
758
759
760
761
762
763
764
765
766
767
768
769
770
771
772
773
774
775
776
777
778
779
780
781
782
783
784
785
786
787
788
789
790
791
792
793
794
795
796
797
798
799
800
801
802
803
804
805
806
807
808
809
810
811
812
813
814
815
816
817
818
819
820
821
822
823
824
825
826
827
828
829
830
831
832
833
834
835
836
837
838
839
840
841
842
843
844
845
846
847
848
849
850
851
852
853
854
855
856
857
858
859
860
861
862
863
864
865
866
867
868
869
870
871
872
873
874
875
876
877
878
879
880
881
882
883
884
885
886
887
888
889
890
891
892
893
894
895
896
897
898
899
900
901
902
903
904
905
906
907
908
909
910
911
912
913
914
915
916
917
918
919
920
921
922
923
924
925
926
927
928
929
930
931
932
933
934
935
936
937
938
939
940
941
942
943
944
945
946
947
948
949
950
951
952
953
954
955
956
957
958
959
960
961
962
963
964
965
966
967
968
969
970
971
972
973
974
975
976
977
978
979
980
981
982
983
984
985
986
987
988
989
990
991
992
993
994
995
996
997
998
999
1000
1001
1002
1003
1004
1005
1006
1007
1008
1009
1010
1011
1012
1013
1014
1015
1016
1017
1018
1019
1020
1021
1022
1023
1024
1025
1026
1027
1028
1029
1030
1031
1032
1033
1034
1035
1036
1037
1038
1039
1040
1041
1042
1043
1044
1045
1046
1047
1048
1049
1050
1051
1052
1053
1054
1055
1056
1057
1058
1059
1060
1061
1062
1063
1064
1065
1066
1067
1068
1069
1070
1071
1072
1073
1074
1075
1076
1077
1078
1079
1080
1081
1082
1083
1084
1085
1086
1087
1088
1089
1090
1091
1092
1093
1094
1095
1096
1097
1098
1099
1100
1101
1102
1103
1104
1105
1106
1107
1108
1109
1110
1111
1112
1113
1114
1115
1116
1117
1118
1119
1120
1121
1122
1123
1124
1125
1126
1127
1128
1129
1130
1131
1132
1133
1134
1135
1136
1137
1138
1139
1140
1141
1142
1143
1144
1145
1146
1147
1148
1149
1150
1151
1152
1153
1154
1155
1156
1157
1158
1159
1160
1161
1162
1163
1164
1165
1166
1167
1168
1169
1170
1171
1172
1173
1174
1175
1176
1177
1178
1179
1180
1181
1182
1183
1184
1185
1186
1187
1188
1189
1190
1191
1192
1193
1194
1195
1196
1197
1198
1199
1200
1201
1202
1203
1204
1205
1206
1207
1208
1209
1210
1211
1212
1213
1214
1215
1216
1217
1218
1219
1220
1221
1222
1223
1224
1225
1226
1227
1228
1229
1230
1231
1232
1233
1234
1235
1236
1237
1238
1239
1240
1241
1242
1243
1244
1245
1246
1247
1248
1249
1250
1251
1252
1253
1254
1255
1256
1257
1258
1259
1260
1261
1262
1263
1264
1265
1266
1267
1268
1269
1270
1271
1272
1273
1274
1275
1276
1277
1278
1279
1280
1281
1282
1283
1284
1285
1286
1287
1288
1289
1290
1291
1292
1293
1294
1295
1296
1297
1298
1299
1300
1301
1302
1303
1304
1305
1306
1307
1308
1309
1310
1311
1312
1313
1314
1315
1316
1317
1318
1319
1320
1321
1322
1323
1324
1325
1326
1327
1328
1329
1330
1331
1332
1333
1334
1335
1336
1337
1338
1339
1340
1341
1342
1343
1344
1345
1346
1347
1348
1349
1350
1351
1352
1353
1354
1355
1356
1357
1358
1359
1360
1361
1362
1363
1364
1365
1366
1367
1368
1369
1370
1371
1372
1373
1374
1375
1376
1377
1378
1379
1380
1381
1382
1383
1384
1385
1386
1387
1388
1389
1390
1391
1392
1393
1394
1395
1396
1397
1398
1399
1400
1401
1402
1403
1404
1405
1406
1407
1408
1409
1410
1411
1412
1413
1414
1415
1416
1417
1418
1419
1420
1421
1422
1423
1424
1425
1426
1427
1428
1429
1430
1431
1432
1433
1434
1435
1436
1437
1438
1439
1440
1441
1442
1443
1444
1445
1446
1447
1448
1449
1450
1451
1452
1453
1454
1455
1456
1457
1458
1459
1460
1461
1462
1463
1464
1465
1466
1467
1468
1469
1470
1471
1472
1473
1474
1475
1476
1477
1478
1479
1480
1481
1482
1483
1484
1485
1486
1487
1488
1489
1490
1491
1492
1493
1494
1495
1496
1497
1498
1499
1500
1501
1502
1503
1504
1505
1506
1507
1508
1509
1510
1511
1512
1513
1514
1515
1516
1517
1518
1519
1520
1521
1522
1523
1524
1525
1526
1527
1528
1529
1530
1531
1532
1533
1534
1535
1536
1537
1538
1539
1540
1541
1542
1543
1544
1545
1546
1547
1548
1549
1550
1551
1552
1553
1554
1555
1556
1557
1558
1559
1560
1561
1562
1563
1564
1565
1566
1567
1568
1569
1570
1571
1572
1573
1574
1575
1576
1577
1578
1579
1580
1581
1582
1583
1584
1585
1586
1587
1588
1589
1590
1591
1592
1593
1594
1595
1596
1597
1598
1599
/* ============================================================
 *
 * This file is a part of digiKam project
 * http://www.digikam.org
 *
 * Date        : 2004-06-18
 * Description : database album interface.
 *
 * Copyright (C) 2004-2005 by Renchi Raju <renchi@pooh.tam.uiuc.edu>
 * Copyright (C) 2006-2007 by Gilles Caulier <caulier dot gilles at gmail dot com>
 * Copyright (C) 2006-2007 by Marcel Wiesweg <marcel dot wiesweg at gmx dot de>
 * 
 * This program is free software; you can redistribute it
 * and/or modify it under the terms of the GNU General
 * Public License as published by the Free Software Foundation;
 * either version 2, or (at your option)
 * any later version.
 *
 * This program is distributed in the hope that it will be useful,
 * but WITHOUT ANY WARRANTY; without even the implied warranty of
 * MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE.  See the
 * GNU General Public License for more details.
 *
 * ============================================================ */

/** @file albumdb.cpp */

// C Ansi includes.

extern "C"
{
#include "sqlite3.h"
#include <sys/time.h>
}

// C++ includes.

#include <cstdio>
#include <cstdlib>
#include <ctime>

// TQt includes.

#include <tqfile.h>
#include <tqfileinfo.h>
#include <tqdir.h>

// KDE includes.

#include <tdelocale.h>

// Local includes.

#include "ddebug.h"
#include "albummanager.h"
#include "album.h"
#include "albumdb.h"
#include "albumsettings.h"

namespace Digikam
{

typedef struct sqlite3_stmt sqlite3_stmt;
typedef struct sqlite3 sqleet3;            // hehe.

class AlbumDBPriv
{

public:

    AlbumDBPriv()
    {
        valid    = false;
        dataBase = 0;
    }

    bool     valid;

    sqleet3 *dataBase;

    IntList  recentlyAssignedTags;
};

AlbumDB::AlbumDB()
{
    d = new AlbumDBPriv;
}

AlbumDB::~AlbumDB()
{
    if (d->dataBase)
    {
        sqlite3_close(d->dataBase);
    }

    delete d;
}

bool AlbumDB::isValid() const
{
    return d->valid; 
}

void AlbumDB::setDBPath(const TQString& path)
{
    if (d->dataBase)
    {
        sqlite3_close(d->dataBase);
        d->dataBase = 0;
    }

    d->valid = false;

    sqlite3_open(TQFile::encodeName(path), &d->dataBase);
    if (d->dataBase == 0)
    {
        DWarning() << "Cannot open database: "
                    << sqlite3_errmsg(d->dataBase)
                    << endl;
    }
    else
    {
        initDB();
    }
}

void AlbumDB::initDB()
{
    d->valid = false;

    // Check if we have the required tables

    TQStringList values;

    if (!execSql( TQString("SELECT name FROM sqlite_master"
                          " WHERE type='table'"
                          " ORDER BY name;"),
                  &values ))
    {
        return;
    }

    if (!values.contains("Albums"))
    {
        if (!execSql( TQString("CREATE TABLE Albums\n"
                              " (id INTEGER PRIMARY KEY,\n"
                              "  url TEXT NOT NULL UNIQUE,\n"
                              "  date DATE NOT NULL,\n"
                              "  caption TEXT,\n"
                              "  collection TEXT,\n"
                              "  icon INTEGER);") ))
        {
            return;
        }

        if (!execSql( TQString("CREATE TABLE Tags\n"
                              " (id INTEGER PRIMARY KEY,\n"
                              "  pid INTEGER,\n"
                              "  name TEXT NOT NULL,\n"
                              "  icon INTEGER,\n"
                              "  iconkde TEXT,\n"
                              "  UNIQUE (name, pid));") ))
        {
            return;
        }

        if (!execSql( TQString("CREATE TABLE TagsTree\n"
                              " (id INTEGER NOT NULL,\n"
                              "  pid INTEGER NOT NULL,\n"
                              "  UNIQUE (id, pid));") ))
        {
            return;
        }

        if (!execSql( TQString("CREATE TABLE Images\n"
                              " (id INTEGER PRIMARY KEY,\n"
                              "  name TEXT NOT NULL,\n"
                              "  dirid INTEGER NOT NULL,\n"
                              "  caption TEXT,\n"
                              "  datetime DATETIME,\n"
                              "  UNIQUE (name, dirid));") ))
        {
            return;
        }


        if (!execSql( TQString("CREATE TABLE ImageTags\n"
                              " (imageid INTEGER NOT NULL,\n"
                              "  tagid INTEGER NOT NULL,\n"
                              "  UNIQUE (imageid, tagid));") ))
        {
            return;
        }

        if (!execSql( TQString("CREATE TABLE ImageProperties\n"
                              " (imageid  INTEGER NOT NULL,\n"
                              "  property TEXT    NOT NULL,\n"
                              "  value    TEXT    NOT NULL,\n"
                              "  UNIQUE (imageid, property));") ))
        {
            return;
        }

        if ( !execSql( TQString( "CREATE TABLE Searches  \n"
                                " (id INTEGER PRIMARY KEY, \n"
                                "  name TEXT NOT NULL UNIQUE, \n"
                                "  url  TEXT NOT NULL);" ) ) )
        {
            return;
        }

        if (!execSql( TQString("CREATE TABLE Settings         \n"
                              "(keyword TEXT NOT NULL UNIQUE,\n"
                              " value TEXT);") ))
            return;
        else
            setSetting("DBVersion","1");

        // TODO: see which more indices are needed
        // create indices
        execSql("CREATE INDEX dir_index ON Images    (dirid);");
        execSql("CREATE INDEX tag_index ON ImageTags (tagid);");

        // create triggers

        // trigger: delete from Images/ImageTags/ImageProperties
        // if Album has been deleted
        execSql("CREATE TRIGGER delete_album DELETE ON Albums\n"
                "BEGIN\n"
                " DELETE FROM ImageTags\n"
                "   WHERE imageid IN (SELECT id FROM Images WHERE dirid=OLD.id);\n"
                " DELETE From ImageProperties\n"
                "   WHERE imageid IN (SELECT id FROM Images WHERE dirid=OLD.id);\n"
                " DELETE FROM Images\n"
                "   WHERE dirid = OLD.id;\n"
                "END;");

        // trigger: delete from ImageTags/ImageProperties
        // if Image has been deleted
        execSql("CREATE TRIGGER delete_image DELETE ON Images\n"
                "BEGIN\n"
                "  DELETE FROM ImageTags\n"
                "    WHERE imageid=OLD.id;\n"
                "  DELETE From ImageProperties\n "
                "    WHERE imageid=OLD.id;\n"
                "  UPDATE Albums SET icon=null \n "
                "    WHERE icon=OLD.id;\n"
                "  UPDATE Tags SET icon=null \n "
                "    WHERE icon=OLD.id;\n"
                "END;");

        // trigger: delete from ImageTags if Tag has been deleted
        execSql("CREATE TRIGGER delete_tag DELETE ON Tags\n"
                "BEGIN\n"
                "  DELETE FROM ImageTags WHERE tagid=OLD.id;\n"
                "END;");

        // trigger: insert into TagsTree if Tag has been added
        execSql("CREATE TRIGGER insert_tagstree AFTER INSERT ON Tags\n"
                "BEGIN\n"
                "  INSERT INTO TagsTree\n"
                "    SELECT NEW.id, NEW.pid\n"
                "    UNION\n"
                "    SELECT NEW.id, pid FROM TagsTree WHERE id=NEW.pid;\n"
                "END;");

        // trigger: delete from TagsTree if Tag has been deleted
        execSql("CREATE TRIGGER delete_tagstree DELETE ON Tags\n"
                "BEGIN\n"
                " DELETE FROM Tags\n"
                "   WHERE id  IN (SELECT id FROM TagsTree WHERE pid=OLD.id);\n"
                " DELETE FROM TagsTree\n"
                "   WHERE id IN (SELECT id FROM TagsTree WHERE pid=OLD.id);\n"
                " DELETE FROM TagsTree\n"
                "    WHERE id=OLD.id;\n"
                "END;");

        // trigger: delete from TagsTree if Tag has been deleted
        execSql("CREATE TRIGGER move_tagstree UPDATE OF pid ON Tags\n"
                "BEGIN\n"
                "  DELETE FROM TagsTree\n"
                "    WHERE\n"
                "      ((id = OLD.id)\n"
                "        OR\n"
                "        id IN (SELECT id FROM TagsTree WHERE pid=OLD.id))\n"
                "      AND\n"
                "      pid IN (SELECT pid FROM TagsTree WHERE id=OLD.id);\n"
                "  INSERT INTO TagsTree\n"
                "     SELECT NEW.id, NEW.pid\n"
                "     UNION\n"
                "     SELECT NEW.id, pid FROM TagsTree WHERE id=NEW.pid\n"
                "     UNION\n"
                "     SELECT id, NEW.pid FROM TagsTree WHERE pid=NEW.id\n"
                "     UNION\n"
                "     SELECT A.id, B.pid FROM TagsTree A, TagsTree B\n"
                "        WHERE\n"
                "        A.pid = NEW.id AND B.id = NEW.pid;\n"
                "END;");
    }

    d->valid = true;
}

AlbumInfo::List AlbumDB::scanAlbums()
{
    AlbumInfo::List aList;

    TQString basePath(AlbumManager::instance()->getLibraryPath());

    TQStringList values;
    execSql( "SELECT A.id, A.url, A.date, A.caption, A.collection, B.url, I.name \n "
             "FROM Albums AS A \n "
             "  LEFT OUTER JOIN Images AS I ON A.icon=I.id \n"
             "  LEFT OUTER JOIN Albums AS B ON B.id=I.dirid;", &values);

    TQString iconAlbumUrl, iconName;

    for (TQStringList::iterator it = values.begin(); it != values.end();)
    {
        AlbumInfo info;

        info.id = (*it).toInt();
        ++it;
        info.url = *it;
        ++it;
        info.date = TQDate::fromString(*it, Qt::ISODate);
        ++it;
        info.caption = *it;
        ++it;
        info.collection = *it;
        ++it;
        iconAlbumUrl = *it;
        ++it;
        iconName = *it;
        ++it;

        if (!iconName.isEmpty())
        {
            info.icon = basePath + iconAlbumUrl + '/' + iconName;
        }

        aList.append(info);
    }

    return aList;
}

TagInfo::List AlbumDB::scanTags()
{
    TagInfo::List tList;

    TQString basePath(AlbumManager::instance()->getLibraryPath());

    TQStringList values;
    execSql( "SELECT T.id, T.pid, T.name, A.url, I.name, T.iconkde \n "
             "FROM Tags AS T LEFT OUTER JOIN Images AS I ON I.id=T.icon \n "
             "  LEFT OUTER JOIN Albums AS A ON A.id=I.dirid; ", &values );

    TQString iconName, iconKDE, albumURL;

    for (TQStringList::iterator it = values.begin(); it != values.end();)
    {
        TagInfo info;

        info.id     = (*it).toInt();
        ++it;
        info.pid    = (*it).toInt();
        ++it;
        info.name   = *it;
        ++it;
        albumURL    = *it;
        ++it;
        iconName    = *it;
        ++it;
        iconKDE     = *it;
        ++it;

        if ( albumURL.isEmpty() )
        {
            info.icon = iconKDE;
        }
        else
        {
            info.icon = basePath + albumURL + '/' + iconName;
        }

        tList.append(info);
    }

    return tList;
}

SearchInfo::List AlbumDB::scanSearches()
{
    SearchInfo::List searchList;    

    TQStringList values;
    execSql( "SELECT id, name, url FROM Searches;", &values);

    for (TQStringList::iterator it = values.begin(); it != values.end();)
    {
        SearchInfo info;

        info.id   = (*it).toInt();
        ++it;
        info.name = (*it);
        ++it;
        info.url  = (*it);
        ++it;

        searchList.append(info);        
    }

    return searchList;
}

void AlbumDB::beginTransaction()
{
    execSql( "BEGIN TRANSACTION;" );
}

void AlbumDB::commitTransaction()
{
    execSql( "COMMIT TRANSACTION;" );
}

int AlbumDB::addAlbum(const TQString& url, const TQString& caption,
                      const TQDate& date, const TQString& collection)
{
    if (!d->dataBase)
        return -1;

    execSql( TQString("REPLACE INTO Albums (url, date, caption, collection) "
                     "VALUES('%1', '%2', '%3', '%4');")
             .arg(escapeString(url),
                  date.toString(Qt::ISODate),
                  escapeString(caption),
                  escapeString(collection)));

    int id = sqlite3_last_insert_rowid(d->dataBase);
    return id;
}

void AlbumDB::setAlbumCaption(int albumID, const TQString& caption)
{
    execSql( TQString("UPDATE Albums SET caption='%1' WHERE id=%2;")
             .arg(escapeString(caption),
                  TQString::number(albumID) ));
}

void AlbumDB::setAlbumCollection(int albumID, const TQString& collection)
{
    execSql( TQString("UPDATE Albums SET collection='%1' WHERE id=%2;")
             .arg(escapeString(collection),
                  TQString::number(albumID)) );
}

void AlbumDB::setAlbumDate(int albumID, const TQDate& date)
{
    execSql( TQString("UPDATE Albums SET date='%1' WHERE id=%2;")
             .arg(date.toString(Qt::ISODate))
             .arg(albumID) );
}

void AlbumDB::setAlbumIcon(int albumID, TQ_LLONG iconID)
{
    execSql( TQString("UPDATE Albums SET icon=%1 WHERE id=%2;")
             .arg(iconID)
             .arg(albumID) );
}

    
TQString AlbumDB::getAlbumIcon(int albumID)
{
    TQStringList values;
    execSql( TQString("SELECT B.url, I.name \n "
                     "FROM Albums AS A \n "
                     "  LEFT OUTER JOIN Images AS I ON I.id=A.icon \n "
                     "  LEFT OUTER JOIN Albums AS B ON B.id=I.dirid \n "
                     "WHERE A.id=%1;")
             .arg(albumID), &values );
    if (values.isEmpty())
        return TQString();

    TQStringList::iterator it = values.begin();
    TQString url  = *it;
    ++it;
    TQString icon = *it;
    if (icon.isEmpty())
        return TQString();

    TQString basePath(AlbumManager::instance()->getLibraryPath());
    basePath += url;
    basePath += '/' + icon;

    return basePath;
}

void AlbumDB::deleteAlbum(int albumID)
{
    execSql( TQString("DELETE FROM Albums WHERE id=%1")
             .arg(albumID) );
}

int AlbumDB::addTag(int parentTagID, const TQString& name, const TQString& iconKDE,
                    TQ_LLONG iconID)
{
    if (!d->dataBase)
        return -1;

    if (!execSql( TQString("INSERT INTO Tags (pid, name) "
                          "VALUES( %1, '%2')")
                  .arg(parentTagID)
                  .arg(escapeString(name))))
    {
        return -1;
    }

    int id = sqlite3_last_insert_rowid(d->dataBase);

    if (!iconKDE.isEmpty())
    {
        execSql( TQString("UPDATE Tags SET iconkde='%1' WHERE id=%2;")
                 .arg(escapeString(iconKDE),
                      TQString::number(id)));
    }
    else
    {
        execSql( TQString("UPDATE Tags SET icon=%1 WHERE id=%2;")
                 .arg(iconID)
                 .arg(id));
    }
    
    return id;
}

void AlbumDB::deleteTag(int tagID)
{
    execSql( TQString("DELETE FROM Tags WHERE id=%1")
                 .arg(tagID) );
}

void AlbumDB::setTagIcon(int tagID, const TQString& iconKDE, TQ_LLONG iconID)
{
    if (!iconKDE.isEmpty())
    {
        execSql( TQString("UPDATE Tags SET iconkde='%1', icon=0 WHERE id=%2;")
                 .arg(escapeString(iconKDE), 
                      TQString::number(tagID)));
    }
    else
    {
        execSql( TQString("UPDATE Tags SET icon=%1 WHERE id=%2;")
                 .arg(iconID)
                 .arg(tagID));
    }
}

TQString AlbumDB::getTagIcon(int tagID)
{
    TQStringList values;
    execSql( TQString("SELECT A.url, I.name, T.iconkde \n "
                     "FROM Tags AS T \n "
                     "  LEFT OUTER JOIN Images AS I ON I.id=T.icon \n "
                     "  LEFT OUTER JOIN Albums AS A ON A.id=I.dirid \n "
                     "WHERE T.id=%1;")
             .arg(tagID), &values );

    if (values.isEmpty())
        return TQString();
    
    TQString basePath(AlbumManager::instance()->getLibraryPath());

    TQString iconName, iconKDE, albumURL, icon;

    TQStringList::iterator it = values.begin();

    albumURL    = *it;
    ++it;
    iconName    = *it;
    ++it;
    iconKDE     = *it;
    ++it;

    if ( albumURL.isEmpty() )
    {
        icon = iconKDE;
    }
    else
    {
        icon = basePath + albumURL + '/' + iconName;
    }

    return icon;
}

void AlbumDB::setTagParentID(int tagID, int newParentTagID)
{
    execSql( TQString("UPDATE Tags SET pid=%1 WHERE id=%2;")
             .arg(newParentTagID)
             .arg(tagID) );
}

int AlbumDB::addSearch(const TQString& name, const KURL& url)
{
    if (!d->dataBase)
    return -1;

    TQString str("INSERT INTO Searches (name, url) \n"
                "VALUES('$$@@$$', '$$##$$');");
    str.replace("$$@@$$", escapeString(name));
    str.replace("$$##$$", escapeString(url.url()));
    
    if (!execSql(str))
    {
    return -1;
    }

    return sqlite3_last_insert_rowid(d->dataBase);
}

void AlbumDB::updateSearch(int searchID, const TQString& name,
               const KURL& url)
{
    TQString str = TQString("UPDATE Searches SET name='$$@@$$', url='$$##$$' \n"
                          "WHERE id=%1")
                  .arg(searchID);
    str.replace("$$@@$$", escapeString(name));
    str.replace("$$##$$", escapeString(url.url()));

    execSql(str);
}

void AlbumDB::deleteSearch(int searchID)
{
    execSql( TQString("DELETE FROM Searches WHERE id=%1")
             .arg(searchID) );
}

void AlbumDB::setSetting(const TQString& keyword,
                         const TQString& value )
{
    execSql( TQString("REPLACE into Settings VALUES ('%1','%2');")
             .arg(escapeString(keyword),
                  escapeString(value) ));
}

TQString AlbumDB::getSetting(const TQString& keyword)
{
    TQStringList values;
    execSql( TQString("SELECT value FROM Settings "
                     "WHERE keyword='%1';")
             .arg(escapeString(keyword)), &values );

    if (values.isEmpty())
        return TQString();
    else
        return values[0];
}

bool AlbumDB::execSql(const TQString& sql, TQStringList* const values,
                      const bool debug)
{
    if ( debug )
        DDebug() << "SQL-query: " << sql << endl;

    if ( !d->dataBase )
    {
        DWarning() << k_funcinfo << "SQLite pointer == NULL"
                    << endl;
        return false;
    }

    const char*   tail;
    sqlite3_stmt* stmt;
    int           error;

    //compile SQL program to virtual machine
    error = sqlite3_prepare(d->dataBase, sql.utf8(), -1, &stmt, &tail);
    if ( error != SQLITE_OK )
    {
        DWarning() << k_funcinfo
                    << "sqlite_compile error: "
                    << sqlite3_errmsg(d->dataBase)
                    << " on query: "
                    << sql << endl;
        return false;
    }

    int cols = sqlite3_column_count(stmt);

    while ( true )
    {
        error = sqlite3_step( stmt );

        if ( error == SQLITE_DONE || error == SQLITE_ERROR )
            break;

        //iterate over columns
        for ( int i = 0; values && i < cols; i++ )
        {
            *values << TQString::fromUtf8( (const char*)sqlite3_column_text( stmt, i ) );
        }
    }

    sqlite3_finalize( stmt );

    if ( error != SQLITE_DONE )
    {
        DWarning() << "sqlite_step error: "
                    << sqlite3_errmsg( d->dataBase )
                    << " on query: "
                    << sql << endl;
        return false;
    }

    return true;
}

TQString AlbumDB::escapeString(TQString str) const
{
    str.replace( "'", "''" );
    return str;
}

TQString AlbumDB::getItemCaption(TQ_LLONG imageID)
{
    TQStringList values;

    execSql( TQString("SELECT caption FROM Images "
                     "WHERE id=%1;")
             .arg(imageID),
             &values );

    if (!values.isEmpty())
        return values[0];
    else
        return TQString();
}

TQString AlbumDB::getItemCaption(int albumID, const TQString& name)
{
    TQStringList values;

    execSql( TQString("SELECT caption FROM Images "
                     "WHERE dirid=%1 AND name='%2';")
             .arg(albumID)
             .arg(escapeString(name)),
             &values );

    if (!values.isEmpty())
        return values[0];
    else
        return TQString();
}

TQDateTime AlbumDB::getItemDate(TQ_LLONG imageID)
{
    TQStringList values;

    execSql( TQString("SELECT datetime FROM Images "
                     "WHERE id=%1;")
             .arg(imageID),
             &values );

    if (values.isEmpty())
        return TQDateTime();
    else
        return TQDateTime::fromString(values[0], Qt::ISODate);
}

TQDateTime AlbumDB::getItemDate(int albumID, const TQString& name)
{
    TQStringList values;

    execSql( TQString("SELECT datetime FROM Images "
                     "WHERE dirid=%1 AND name='%2';")
             .arg(albumID)
             .arg(escapeString(name)),
             &values );

    if (values.isEmpty())
        return TQDateTime();
    else
        return TQDateTime::fromString(values[0], Qt::ISODate);
}

TQ_LLONG AlbumDB::getImageId(int albumID, const TQString& name)
{
    TQStringList values;

    execSql( TQString("SELECT id FROM Images "
                     "WHERE dirid=%1 AND name='%2';")
             .arg(albumID)
             .arg(escapeString(name)),
             &values );

    if (values.isEmpty())
        return -1;
    else
        return (values[0]).toLongLong();
}

TQStringList AlbumDB::getItemTagNames(TQ_LLONG imageID)
{
    TQStringList values;

    execSql( TQString("SELECT name FROM Tags \n "
                     "WHERE id IN (SELECT tagid FROM ImageTags \n "
                     "             WHERE imageid=%1) \n "
                     "ORDER BY name;")
             .arg(imageID),
             &values );
    
    return values;
}

IntList AlbumDB::getItemTagIDs(TQ_LLONG imageID)
{
    TQStringList values;

    execSql( TQString("SELECT tagid FROM ImageTags \n "
                     "WHERE imageID=%1;")
             .arg(imageID),
             &values );

    IntList ids;

    if (values.isEmpty())
        return ids;

    for (TQStringList::iterator it=values.begin(); it != values.end(); ++it)
    {
        ids << (*it).toInt();
    }
    return ids;
}

bool AlbumDB::hasTags(const LLongList& imageIDList)
{
    IntList ids;

    if (imageIDList.isEmpty())
        return false;

    TQStringList values;

    TQString sql = TQString("SELECT count(tagid) FROM ImageTags "
            "WHERE imageid=%1 ")
            .arg(imageIDList.first());

    LLongList::const_iterator iter = imageIDList.begin();
    ++iter;

    while (iter != imageIDList.end())
    {
        sql += TQString(" OR imageid=%2 ")
                .arg(*iter);
        ++iter;
    }

    sql += TQString(";");
    execSql( sql, &values );

    if (values[0] == "0")
        return false;
    else
        return true;
}

IntList AlbumDB::getItemCommonTagIDs(const LLongList& imageIDList)
{
    IntList ids;

    if (imageIDList.isEmpty())
        return ids;

    TQStringList values;

    TQString sql = TQString("SELECT DISTINCT tagid FROM ImageTags "
                          "WHERE imageid=%1 ")
                  .arg(imageIDList.first());

    LLongList::const_iterator iter = imageIDList.begin();
    ++iter;

    while (iter != imageIDList.end())
    {
        sql += TQString(" OR imageid=%2 ")
               .arg(*iter);
        ++iter;
    }

    sql += TQString(";");
    execSql( sql, &values );

    if (values.isEmpty())
        return ids;

    for (TQStringList::iterator it=values.begin(); it != values.end(); ++it)
    {
        ids << (*it).toInt();
    }
    return ids;
}

void AlbumDB::setItemCaption(TQ_LLONG imageID,const TQString& caption)
{
    TQStringList values;

    execSql( TQString("UPDATE Images SET caption='%1' "
                     "WHERE id=%2;")
             .arg(escapeString(caption),
                  TQString::number(imageID) ));
}

void AlbumDB::setItemCaption(int albumID, const TQString& name, const TQString& caption)
{
    TQStringList values;

    execSql( TQString("UPDATE Images SET caption='%1' "
                     "WHERE dirid=%2 AND name='%3';")
             .arg(escapeString(caption),
                  TQString::number(albumID),
                  escapeString(name)) );
}

void AlbumDB::addItemTag(TQ_LLONG imageID, int tagID)
{
    execSql( TQString("REPLACE INTO ImageTags (imageid, tagid) "
                     "VALUES(%1, %2);")
                 .arg(imageID)
                 .arg(tagID) );

    if (!d->recentlyAssignedTags.contains(tagID))
    {
        d->recentlyAssignedTags.push_front(tagID);
        if (d->recentlyAssignedTags.size() > 10)
            d->recentlyAssignedTags.pop_back();
    }
}

void AlbumDB::addItemTag(int albumID, const TQString& name, int tagID)
{
    execSql( TQString("REPLACE INTO ImageTags (imageid, tagid) \n "
                     "(SELECT id, %1 FROM Images \n "
                     " WHERE dirid=%2 AND name='%3');")
             .arg(tagID)
             .arg(albumID)
             .arg(escapeString(name)) );
}

IntList AlbumDB::getRecentlyAssignedTags() const
{
    return d->recentlyAssignedTags;    
}

void AlbumDB::removeItemTag(TQ_LLONG imageID, int tagID)
{
    execSql( TQString("DELETE FROM ImageTags "
                     "WHERE imageID=%1 AND tagid=%2;")
             .arg(imageID)
             .arg(tagID) );
}

void AlbumDB::removeItemAllTags(TQ_LLONG imageID)
{
    execSql( TQString("DELETE FROM ImageTags "
                     "WHERE imageID=%1;")
             .arg(imageID) );
}

TQStringList AlbumDB::getItemNamesInAlbum(int albumID, bool recurssive)
{
    TQStringList values;

    if (recurssive)
    {
        KURL url(getAlbumURL(albumID));
        execSql( TQString("SELECT Images.name "
                         "FROM Images "
                         "WHERE Images.dirid "
                         "IN (SELECT DISTINCT id "
                             "FROM Albums "
                             "WHERE url='%1' OR url LIKE '\%%2\%')")
                .arg(escapeString(url.path())).arg(escapeString(url.path(1))), &values);
    }
    else
    {
        execSql( TQString("SELECT Images.name "
                         "FROM Images "
                         "WHERE Images.dirid=%1")
                .arg(albumID), &values );
    }
    return values;
}

TQStringList AlbumDB::getAllItemURLsWithoutDate()
{
    TQStringList values;
    execSql( TQString("SELECT Albums.url||'/'||Images.name "
                     "FROM Images, Albums "
                     "WHERE Images.dirid=Albums.Id "
                     "AND (Images.datetime is null or "
                     "     Images.datetime == '');"),
             &values );

    TQString libraryPath = AlbumManager::instance()->getLibraryPath() + '/';
    for (TQStringList::iterator it = values.begin(); it != values.end();
         ++it)
    {
        *it = libraryPath + *it;
    }

    return values;
}

int AlbumDB::getOrCreateAlbumId(const TQString& folder)
{
    TQStringList values;
    execSql( TQString("SELECT id FROM Albums WHERE url ='%1';")
            .arg( escapeString(folder) ), &values);

    int albumID;
    if (values.isEmpty())
    {
        execSql( TQString ("INSERT INTO Albums (url, date) "
                          "VALUES ('%1','%2')")
                 .arg(escapeString(folder),
                      TQDateTime::currentDateTime().toString(Qt::ISODate)) );
        albumID = sqlite3_last_insert_rowid(d->dataBase);
    } else
        albumID = values[0].toInt();

    return albumID;
}

TQ_LLONG AlbumDB::addItem(int albumID,
                         const TQString& name,
                         const TQDateTime& datetime,
                         const TQString& comment,
                         int rating,
                         const TQStringList &keywordsList)
{
    execSql ( TQString ("REPLACE INTO Images "
                       "( caption , datetime, name, dirid ) "
                       " VALUES ('%1','%2','%3',%4) " )
              .arg(escapeString(comment),
                   datetime.toString(Qt::ISODate),
                   escapeString(name),
                   TQString::number(albumID)) );

    TQ_LLONG item = sqlite3_last_insert_rowid(d->dataBase);

    // Set Rating value to item in database.

    if ( item != -1 && rating != -1 )
        setItemRating(item, rating);

    // Set existing tags in database or create new tags if not exist.

    if ( item != -1 && !keywordsList.isEmpty() )
    {
        IntList tagIDs = getTagsFromTagPaths(keywordsList);
        for (IntList::iterator it = tagIDs.begin(); it != tagIDs.end(); ++it)
        {
            addItemTag(item, *it);
        }
    }

    return item;
}

IntList AlbumDB::getTagsFromTagPaths(const TQStringList &keywordsList, bool create)
{
    if (keywordsList.isEmpty())
        return IntList();

    IntList tagIDs;

    TQStringList keywordsList2Create;

    // Create a list of the tags currently in database

    TagInfo::List currentTagsList;

    TQStringList values;
    execSql( "SELECT id, pid, name FROM Tags;", &values );

    for (TQStringList::iterator it = values.begin(); it != values.end();)
    {
        TagInfo info;

        info.id   = (*it).toInt();
        ++it;
        info.pid  = (*it).toInt();
        ++it;
        info.name = *it;
        ++it;
        currentTagsList.append(info);
    }

    // For every tag in keywordsList, scan taglist to check if tag already exists.

    for (TQStringList::const_iterator kwd = keywordsList.begin();
        kwd != keywordsList.end(); ++kwd )
    {
        // split full tag "url" into list of single tag names
        TQStringList tagHierarchy = TQStringList::split('/', *kwd);
        if (tagHierarchy.isEmpty())
            continue;

        // last entry in list is the actual tag name
        bool foundTag   = false;
        TQString tagName = tagHierarchy.back();
        tagHierarchy.pop_back();

        for (TagInfo::List::iterator tag = currentTagsList.begin();
            tag != currentTagsList.end(); ++tag )
        {
            // There might be multiple tags with the same name, but in different
            // hierarchies. We must check them all until we find the correct hierarchy
            if ((*tag).name == tagName)
            {
                int parentID = (*tag).pid;

                // Check hierarchy, from bottom to top
                bool foundParentTag                 = true;
                TQStringList::iterator parentTagName = tagHierarchy.end();

                while (foundParentTag && parentTagName != tagHierarchy.begin())
                {
                    --parentTagName;

                    foundParentTag = false;

                    for (TagInfo::List::iterator parentTag = currentTagsList.begin();
                        parentTag != currentTagsList.end(); ++parentTag )
                    {
                        // check if name is the same, and if ID is identical
                        // to the parent ID we got from the child tag
                        if ( (*parentTag).id == parentID &&
                            (*parentTag).name == (*parentTagName) )
                        {
                            parentID       = (*parentTag).pid;
                            foundParentTag = true;
                            break;
                        }
                    }

                    // If we traversed the list without a match,
                    // foundParentTag will be false, the while loop breaks.
                }

                // If we managed to traverse the full hierarchy,
                // we have our tag.
                if (foundParentTag)
                {
                    // add to result list
                    tagIDs.append((*tag).id);
                    foundTag = true;
                    break;
                }
            }
        }

        if (!foundTag)
            keywordsList2Create.append(*kwd);
    }

    // If tags do not exist in database, create them.

    if (create && !keywordsList2Create.isEmpty())
    {
        for (TQStringList::iterator kwd = keywordsList2Create.begin();
            kwd != keywordsList2Create.end(); ++kwd )
        {
            // split full tag "url" into list of single tag names
            TQStringList tagHierarchy = TQStringList::split('/', *kwd);

            if (tagHierarchy.isEmpty())
                continue;

            int  parentTagID      = 0;
            int  tagID            = 0;
            bool parentTagExisted = true;

            // Traverse hierarchy from top to bottom
            for (TQStringList::iterator tagName = tagHierarchy.begin();
                tagName != tagHierarchy.end(); ++tagName)
            {
                tagID = 0;

                // if the parent tag did not exist, we need not check if the child exists
                if (parentTagExisted)
                {
                    for (TagInfo::List::iterator tag = currentTagsList.begin();
                        tag != currentTagsList.end(); ++tag )
                    {
                        // find the tag with tag name according to tagHierarchy,
                        // and parent ID identical to the ID of the tag we found in
                        // the previous run.
                        if ((*tag).name == (*tagName) && (*tag).pid == parentTagID)
                        {
                            tagID = (*tag).id;
                            break;
                        }
                    }
                }

                if (tagID != 0)
                {
                    // tag already found in DB
                    parentTagID = tagID;
                    continue;
                }

                // Tag does not yet exist in DB, add it
                tagID = addTag(parentTagID, (*tagName), TQString(), 0);

                if (tagID == -1)
                {
                    // Something is wrong in database. Abort.
                    break;
                }

                // append to our list of existing tags (for following keywords)
                TagInfo info;
                info.id   = tagID;
                info.pid  = parentTagID;
                info.name = (*tagName);
                currentTagsList.append(info);

                parentTagID      = tagID;
                parentTagExisted = false;
            }

            // add to result list
            tagIDs.append(tagID);
        }
    }

    return tagIDs;
}

int AlbumDB::getItemAlbum(TQ_LLONG imageID)
{
    TQStringList values;

    execSql ( TQString ("SELECT dirid FROM Images "
                       "WHERE id=%1;")
              .arg(imageID),
              &values);

    if (!values.isEmpty())
        return values.first().toInt();
    else
        return 1;
}

TQString AlbumDB::getItemName(TQ_LLONG imageID)
{
    TQStringList values;

    execSql ( TQString ("SELECT name FROM Images "
                       "WHERE id=%1;")
              .arg(imageID),
              &values);

    if (!values.isEmpty())
        return values.first();
    else
        return TQString();
}

bool AlbumDB::setItemDate(TQ_LLONG imageID,
                          const TQDateTime& datetime)
{
    execSql ( TQString ("UPDATE Images SET datetime='%1'"
                       "WHERE id=%2;")
              .arg(datetime.toString(Qt::ISODate),
                   TQString::number(imageID)) );

    return true;
}

bool AlbumDB::setItemDate(int albumID, const TQString& name,
                          const TQDateTime& datetime)
{
    execSql ( TQString ("UPDATE Images SET datetime='%1'"
                       "WHERE dirid=%2 AND name='%3';")
              .arg(datetime.toString(Qt::ISODate),
                   TQString::number(albumID),
                   escapeString(name)) );

    return true;
}

void AlbumDB::setItemRating(TQ_LLONG imageID, int rating)
{
    execSql ( TQString ("REPLACE INTO ImageProperties "
                       "(imageid, property, value) "
                       "VALUES(%1, '%2', '%3');")
              .arg(imageID)
              .arg("Rating")
              .arg(rating) );
}

int AlbumDB::getItemRating(TQ_LLONG imageID)
{
    TQStringList values;

    execSql( TQString("SELECT value FROM ImageProperties "
                     "WHERE imageid=%1 and property='%2';")
             .arg(imageID)
             .arg("Rating"),
             &values);

    if (!values.isEmpty())
        return values[0].toInt();
    else
        return 0;
}

TQStringList AlbumDB::getItemURLsInAlbum(int albumID)
{
    TQStringList values;

    TQString basePath(AlbumManager::instance()->getLibraryPath());

    AlbumSettings::ImageSortOrder order = AlbumSettings::instance()->getImageSortOrder();

    TQString sqlString;
    switch(order)
    {
	case AlbumSettings::ByIName:
	    sqlString = TQString("SELECT Albums.url||'/'||Images.name FROM Images, Albums "
				 "WHERE Albums.id=%1 AND Albums.id=Images.dirid "
				 "ORDER BY Images.name COLLATE NOCASE;")
			.arg(albumID);
	    break;
	case AlbumSettings::ByIPath:
	    // Dont collate on the path - this is to maintain the same behaviour
	    // that happens when sort order is "By Path"
	    sqlString = TQString("SELECT Albums.url||'/'||Images.name FROM Images, Albums "
				 "WHERE Albums.id=%1 AND Albums.id=Images.dirid "
				 "ORDER BY Albums.url,Images.name;")
			.arg(albumID);
	    break;
	case AlbumSettings::ByIDate:
	    sqlString = TQString("SELECT Albums.url||'/'||Images.name FROM Images, Albums "
				 "WHERE Albums.id=%1 AND Albums.id=Images.dirid "
				 "ORDER BY Images.datetime;")
			.arg(albumID);
	    break;
	case AlbumSettings::ByIRating:
	    sqlString = TQString("SELECT Albums.url||'/'||Images.name FROM Images, Albums, ImageProperties "
				 "WHERE Albums.id=%1 AND Albums.id=Images.dirid "
				 "AND Images.id = ImageProperties.imageid "
				 "AND ImageProperties.property='Rating' "
				 "ORDER BY ImageProperties.value DESC;")
			.arg(albumID);
	    break;
	default:
	    sqlString = TQString("SELECT Albums.url||'/'||Images.name FROM Images, Albums "
				 "WHERE Albums.id=%1 AND Albums.id=Images.dirid;")
			.arg(albumID);
	    break;
    }
    execSql( sqlString, &values );

    for (TQStringList::iterator it = values.begin(); it != values.end(); ++it)
    {
        *it = basePath + *it;
    }

    return values;
}

LLongList AlbumDB::getItemIDsInAlbum(int albumID)
{
    LLongList itemIDs;

    TQStringList itemNames = getItemNamesInAlbum(albumID);

    for (TQStringList::iterator it = itemNames.begin(); it != itemNames.end(); ++it)
    {
        TQ_LLONG id = getImageId(albumID, *it);
        itemIDs.append(id);
    }

    return itemIDs;
}

TQStringList AlbumDB::getItemURLsInTag(int tagID, bool recursive)
{
    TQStringList values;

    TQString basePath(AlbumManager::instance()->getLibraryPath());

    TQString imagesIdClause;
    if (recursive)
        imagesIdClause = TQString("SELECT imageid FROM ImageTags "
                                 " WHERE tagid=%1 "
                                 " OR tagid IN (SELECT id FROM TagsTree WHERE pid=%2)")
                                .arg(tagID).arg(tagID);
    else
        imagesIdClause = TQString("SELECT imageid FROM ImageTags WHERE tagid=%1").arg(tagID);

    execSql( TQString("SELECT Albums.url||'/'||Images.name FROM Images, Albums "
                     "WHERE Images.id IN (%1) "
                     "AND Albums.id=Images.dirid;")
             .arg(imagesIdClause), &values );

    for (TQStringList::iterator it = values.begin(); it != values.end(); ++it)
    {
        *it = basePath + *it;
    }

    return values;
}

LLongList AlbumDB::getItemIDsInTag(int tagID, bool recursive)
{
    LLongList itemIDs;
    TQStringList values;

    if (recursive)
        execSql( TQString("SELECT imageid FROM ImageTags "
                         " WHERE tagid=%1 "
                         " OR tagid IN (SELECT id FROM TagsTree WHERE pid=%2)")
                .arg(tagID).arg(tagID), &values );
    else
        execSql( TQString("SELECT imageid FROM ImageTags WHERE tagid=%1;")
                .arg(tagID), &values );

    for (TQStringList::iterator it = values.begin(); it != values.end(); ++it)
    {
        itemIDs << (*it).toLong();
    }

    return itemIDs;
}

TQString AlbumDB::getAlbumURL(int albumID)
{
    TQStringList values;
    execSql( TQString("SELECT url from Albums where id=%1")
             .arg( albumID), &values);
    return values[0];
}

TQDate AlbumDB::getAlbumLowestDate(int albumID)
{
    TQStringList values;
    execSql( TQString("SELECT MIN(datetime) FROM Images "
                     "WHERE dirid=%1 GROUP BY dirid")
            .arg( albumID ), &values);
    TQDate itemDate = TQDate::fromString( values[0], Qt::ISODate );
    return itemDate;
}

TQDate AlbumDB::getAlbumHighestDate(int albumID)
{
    TQStringList values;
    execSql( TQString("SELECT MAX(datetime) FROM Images "
                     "WHERE dirid=%1 GROUP BY dirid")
            .arg( albumID ), &values);
    TQDate itemDate = TQDate::fromString( values[0], Qt::ISODate );
    return itemDate;
}

TQDate AlbumDB::getAlbumAverageDate(int albumID)
{
    TQStringList values;
    execSql( TQString("SELECT datetime FROM Images WHERE dirid=%1")
            .arg( albumID ), &values);

    int differenceInSecs = 0;
    int amountOfImages = 0;
    TQDateTime baseDateTime;

    for (TQStringList::iterator it = values.begin(); it != values.end(); ++it)
    {
        TQDateTime itemDateTime = TQDateTime::fromString( *it, Qt::ISODate );
        if (itemDateTime.isValid())
        {
            ++amountOfImages;
            if ( baseDateTime.isNull() )
                baseDateTime=itemDateTime;
            else
                differenceInSecs += itemDateTime.secsTo( baseDateTime );
        }
    }

    if ( amountOfImages > 0 )
    {
        TQDateTime averageDateTime;
        averageDateTime.setTime_t( baseDateTime.toTime_t() -
                                   (int)( differenceInSecs/amountOfImages ) );
        return ( averageDateTime.date() );
    }
    else
        return TQDate();
}

void AlbumDB::deleteItem(int albumID, const TQString& file)
{
    execSql( TQString("DELETE FROM Images "
                     "WHERE dirid=%1 AND name='%2';")
             .arg(albumID)
             .arg(escapeString(file)) );
}

void AlbumDB::setAlbumURL(int albumID, const TQString& url)
{
    TQString u = escapeString(url);

    // first delete any stale albums left behind
    execSql( TQString("DELETE FROM Albums WHERE url = '%1'")
             .arg(u) );

    // now update the album url
    execSql( TQString("UPDATE Albums SET url = '%1' WHERE id = %2;")
             .arg(u, TQString::number(albumID) ));
}

void AlbumDB::setTagName(int tagID, const TQString& name)
{
    execSql( TQString("UPDATE Tags SET name='%1' WHERE id=%2;")
             .arg(escapeString(name), TQString::number(tagID) ));
}

void AlbumDB::moveItem(int srcAlbumID, const TQString& srcName,
                       int dstAlbumID, const TQString& dstName)
{

    // first delete any stale database entries if any
    deleteItem(dstAlbumID, dstName);

    execSql( TQString("UPDATE Images SET dirid=%1, name='%2' "
                     "WHERE dirid=%3 AND name='%4';")
             .arg(TQString::number(dstAlbumID), escapeString(dstName),
                  TQString::number(srcAlbumID), escapeString(srcName)) );
}

int AlbumDB::copyItem(int srcAlbumID, const TQString& srcName,
                      int dstAlbumID, const TQString& dstName)
{
    // check for src == dest
    if (srcAlbumID == dstAlbumID && srcName == dstName)
        return -1;

    // find id of src image
    TQStringList values;
    execSql( TQString("SELECT id FROM Images "
                     "WHERE dirid=%1 AND name='%2';")
             .arg(TQString::number(srcAlbumID), escapeString(srcName)),
             &values);

    if (values.isEmpty())
        return -1;

    int srcId = values[0].toInt();

    // first delete any stale database entries if any
    deleteItem(dstAlbumID, dstName);

    // copy entry in Images table
    execSql( TQString("INSERT INTO Images (dirid, name, caption, datetime) "
                     "SELECT %1, '%2', caption, datetime FROM Images "
                     "WHERE id=%3;")
             .arg(TQString::number(dstAlbumID), escapeString(dstName),
                  TQString::number(srcId)) );

    int dstId = sqlite3_last_insert_rowid(d->dataBase);

    // copy tags
    execSql( TQString("INSERT INTO ImageTags (imageid, tagid) "
                     "SELECT %1, tagid FROM ImageTags "
                     "WHERE imageid=%2;")
             .arg(TQString::number(dstId), TQString::number(srcId)) );

    // copy properties (rating)
    execSql( TQString("INSERT INTO ImageProperties (imageid, property, value) "
                     "SELECT %1, property, value FROM ImageProperties "
                     "WHERE imageid=%2;")
             .arg(TQString::number(dstId), TQString::number(srcId)) );

    return dstId;
}

TQ_LLONG AlbumDB::lastInsertedRow()
{
    return sqlite3_last_insert_rowid(d->dataBase);    
}

}  // namespace Digikam