forked from project-chip/zap
-
Notifications
You must be signed in to change notification settings - Fork 0
/
Copy pathzap-schema.sql
3888 lines (3833 loc) · 117 KB
/
zap-schema.sql
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
/*
*
* $$$$$$$\ $$\
* $$ __$$\ $$ |
* $$ | $$ |$$$$$$\ $$$$$$$\ $$ | $$\ $$$$$$\ $$$$$$\ $$$$$$\ $$$$$$$\
* $$$$$$$ |\____$$\ $$ _____|$$ | $$ |\____$$\ $$ __$$\ $$ __$$\ $$ _____|
* $$ ____/ $$$$$$$ |$$ / $$$$$$ / $$$$$$$ |$$ / $$ |$$$$$$$$ |\$$$$$$\
* $$ | $$ __$$ |$$ | $$ _$$< $$ __$$ |$$ | $$ |$$ ____| \____$$\
* $$ | \$$$$$$$ |\$$$$$$$\ $$ | \$$\\$$$$$$$ |\$$$$$$$ |\$$$$$$$\ $$$$$$$ |
* \__| \_______| \_______|\__| \__|\_______| \____$$ | \_______|\_______/
* $$\ $$ |
* \$$$$$$ |
* \______/
*
* You can create these giant separators via:
* http://patorjk.com/software/taag/#p=display&f=Big%20Money-nw
*/
/*
Global SQLite settings.
*/
PRAGMA foreign_keys = ON;
/*
PACKAGE table contains the "packages" that are the sources for the
loading of the other data. They may be individual files, or
collection of files, which then contain subpackages.
Table records the CRC of the toplevel file at the time loading.
Note: This table does not have unique keys because we could have top
level packages which are reloaded because one of the packages
changed. So there could be multiple top level packages with same
path and crc but there will be only one of them which will have
IS_IN_SYNC as 1.
*/
DROP TABLE IF EXISTS "PACKAGE";
CREATE TABLE "PACKAGE" (
"PACKAGE_ID" integer primary key autoincrement,
"PARENT_PACKAGE_REF" integer,
"PATH" text NOT NULL,
"TYPE" text,
"CRC" integer,
"VERSION" integer,
"CATEGORY" text,
"DESCRIPTION" text,
"IS_IN_SYNC" boolean default 1,
foreign key (PARENT_PACKAGE_REF) references PACKAGE(PACKAGE_ID) ON DELETE CASCADE ON UPDATE CASCADE
);
/*
PACKAGE_OPTION table contains generic 'options' that are encoded from within each packages.
*/
DROP TABLE IF EXISTS "PACKAGE_OPTION";
CREATE TABLE "PACKAGE_OPTION" (
"OPTION_ID" integer primary key autoincrement,
"PACKAGE_REF" integer,
"OPTION_CATEGORY" text,
"OPTION_CODE" text,
"OPTION_LABEL" text,
foreign key (PACKAGE_REF) references PACKAGE(PACKAGE_ID) ON DELETE CASCADE ON UPDATE CASCADE,
UNIQUE(PACKAGE_REF, OPTION_CATEGORY, OPTION_CODE, OPTION_LABEL)
);
/*
PACKAGE_OPTION_DEFAULT table contains a link to a specified 'default value' for options
*/
DROP TABLE IF EXISTS "PACKAGE_OPTION_DEFAULT";
CREATE TABLE "PACKAGE_OPTION_DEFAULT" (
"OPTION_DEFAULT_ID" integer primary key autoincrement,
"PACKAGE_REF" integer,
"OPTION_CATEGORY" text,
"OPTION_REF" integer,
foreign key (PACKAGE_REF) references PACKAGE(PACKAGE_ID) ON DELETE CASCADE ON UPDATE CASCADE,
foreign key (OPTION_REF) references PACKAGE_OPTION(OPTION_ID) ON DELETE CASCADE ON UPDATE CASCADE,
UNIQUE(PACKAGE_REF, OPTION_CATEGORY)
);
/*
PACKAGE EXTENSIONS table contains extensions of specific ZCL entities attached to the
gen template packages. See docs/sdk-extensions.md, the section about "Template key: zcl"
*/
DROP TABLE IF EXISTS "PACKAGE_EXTENSION";
CREATE TABLE "PACKAGE_EXTENSION" (
"PACKAGE_EXTENSION_ID" integer primary key autoincrement,
"PACKAGE_REF" integer,
"ENTITY" text,
"PROPERTY" text,
"TYPE" text,
"CONFIGURABILITY" text,
"LABEL" text,
"GLOBAL_DEFAULT" text,
foreign key (PACKAGE_REF) references PACKAGE(PACKAGE_ID) ON DELETE CASCADE ON UPDATE CASCADE,
UNIQUE(PACKAGE_REF, ENTITY, PROPERTY)
);
/*
PACKAGE_EXTENSION_DEFAULTS table contains default values for specific entities. Each row provides
default value for one item of a given entity, listed in PACKAGE_EXTENSION
*/
DROP TABLE IF EXISTS "PACKAGE_EXTENSION_DEFAULT";
CREATE TABLE "PACKAGE_EXTENSION_DEFAULT" (
"PACKAGE_EXTENSION_REF" integer,
"ENTITY_CODE" integer,
"ENTITY_QUALIFIER" text,
"PARENT_CODE" integer,
"MANUFACTURER_CODE" integer,
"VALUE" text,
foreign key (PACKAGE_EXTENSION_REF) references PACKAGE_EXTENSION(PACKAGE_EXTENSION_ID) ON DELETE CASCADE ON UPDATE CASCADE
);
/*
*
* $$$$$$$$\ $$\ $$\ $$\ $$\ $$\
* \____$$ | $$ | $$$\ $$$ | $$ | $$ |
* $$ / $$$$$$$\ $$ | $$$$\ $$$$ | $$$$$$\ $$$$$$$ | $$$$$$\ $$ |
* $$ / $$ _____|$$ | $$\$$\$$/$$ |$$ __$$\ $$ __$$ |$$ __$$\ $$ |
* $$ / $$ / $$ | $$ \$$$ .$$ |$$ / $$ |$$ / $$ |$$$$$$$$ |$$ |
* $$ / $$ | $$ | $$ |\$ /$$ |$$ | $$ |$$ | $$ |$$ ____|$$ |
* $$$$$$$$\\$$$$$$$\ $$ | $$ | \_/ $$ |\$$$$$$ |\$$$$$$$ |\$$$$$$$\ $$ |
* \________|\_______|\__| \__| \__| \______/ \_______| \_______|\__|
*/
/*
SPEC table contains the spec information.
*/
DROP TABLE IF EXISTS "SPEC";
CREATE TABLE IF NOT EXISTS "SPEC" (
"SPEC_ID" integer primary key autoincrement,
"PACKAGE_REF" integer,
"CODE" text NOT NULL,
"DESCRIPTION" text,
"CERTIFIABLE" integer,
foreign key (PACKAGE_REF) references PACKAGE(PACKAGE_ID) ON DELETE CASCADE ON UPDATE CASCADE,
UNIQUE(PACKAGE_REF, CODE)
);
/*
DOMAIN table contains domains directly loaded from packages.
*/
DROP TABLE IF EXISTS "DOMAIN";
CREATE TABLE IF NOT EXISTS "DOMAIN" (
"DOMAIN_ID" integer primary key autoincrement,
"PACKAGE_REF" integer,
"NAME" text,
"LATEST_SPEC_REF" integer,
foreign key (PACKAGE_REF) references PACKAGE(PACKAGE_ID) ON DELETE CASCADE ON UPDATE CASCADE,
foreign key (LATEST_SPEC_REF) references SPEC(SPEC_ID) ON DELETE CASCADE ON UPDATE CASCADE,
UNIQUE(PACKAGE_REF, NAME)
);
/*
CLUSTER table contains the clusters loaded from the ZCL XML files.
*/
DROP TABLE IF EXISTS "CLUSTER";
CREATE TABLE IF NOT EXISTS "CLUSTER" (
"CLUSTER_ID" integer primary key autoincrement,
"PACKAGE_REF" integer,
"DOMAIN_NAME" text,
"CODE" integer,
"MANUFACTURER_CODE" integer,
"NAME" text,
"DESCRIPTION" text,
"DEFINE" text,
"IS_SINGLETON" integer,
"REVISION" integer,
"INTRODUCED_IN_REF" integer,
"REMOVED_IN_REF" integer,
"API_MATURITY" text,
foreign key (INTRODUCED_IN_REF) references SPEC(SPEC_ID) ON DELETE CASCADE ON UPDATE CASCADE,
foreign key (REMOVED_IN_REF) references SPEC(SPEC_ID) ON DELETE CASCADE ON UPDATE CASCADE,
foreign key (PACKAGE_REF) references PACKAGE(PACKAGE_ID) ON DELETE CASCADE ON UPDATE CASCADE
UNIQUE(PACKAGE_REF, CODE, MANUFACTURER_CODE)
);
/*
COMMAND table contains commands contained inside a cluster.
*/
DROP TABLE IF EXISTS "COMMAND";
CREATE TABLE IF NOT EXISTS "COMMAND" (
"COMMAND_ID" integer primary key autoincrement,
"CLUSTER_REF" integer,
"PACKAGE_REF" integer,
"CODE" integer,
"MANUFACTURER_CODE" integer,
"NAME" text,
"DESCRIPTION" text,
"SOURCE" text,
"IS_OPTIONAL" integer,
"MUST_USE_TIMED_INVOKE" integer,
"IS_FABRIC_SCOPED" integer,
"INTRODUCED_IN_REF" integer,
"REMOVED_IN_REF" integer,
"RESPONSE_NAME" integer,
"RESPONSE_REF" integer,
"IS_DEFAULT_RESPONSE_ENABLED" integer,
foreign key (INTRODUCED_IN_REF) references SPEC(SPEC_ID) ON DELETE CASCADE ON UPDATE CASCADE,
foreign key (REMOVED_IN_REF) references SPEC(SPEC_ID) ON DELETE CASCADE ON UPDATE CASCADE,
foreign key (CLUSTER_REF) references CLUSTER(CLUSTER_ID) ON DELETE CASCADE ON UPDATE CASCADE,
foreign key (PACKAGE_REF) references PACKAGE(PACKAGE_ID) ON DELETE CASCADE ON UPDATE CASCADE,
foreign key (RESPONSE_REF) references COMMAND(COMMAND_ID) ON DELETE CASCADE ON UPDATE CASCADE
UNIQUE(CLUSTER_REF, PACKAGE_REF, CODE, MANUFACTURER_CODE, SOURCE)
);
/*
COMMAND_ARG table contains arguments for a command.
*/
DROP TABLE IF EXISTS "COMMAND_ARG";
CREATE TABLE IF NOT EXISTS "COMMAND_ARG" (
"COMMAND_REF" integer,
"FIELD_IDENTIFIER" integer,
"NAME" text,
"TYPE" text,
"MIN" text,
"MAX" text,
"MIN_LENGTH" integer,
"MAX_LENGTH" integer,
"IS_ARRAY" integer,
"PRESENT_IF" text,
"IS_NULLABLE" integer,
"IS_OPTIONAL" integer,
"COUNT_ARG" text,
"INTRODUCED_IN_REF" integer,
"REMOVED_IN_REF" integer,
foreign key (INTRODUCED_IN_REF) references SPEC(SPEC_ID) ON DELETE CASCADE ON UPDATE CASCADE,
foreign key (REMOVED_IN_REF) references SPEC(SPEC_ID) ON DELETE CASCADE ON UPDATE CASCADE,
foreign key (COMMAND_REF) references COMMAND(COMMAND_ID) ON DELETE CASCADE ON UPDATE CASCADE
UNIQUE(COMMAND_REF, FIELD_IDENTIFIER)
);
/*
EVENT table contains events for a given cluster.
*/
DROP TABLE IF EXISTS "EVENT";
CREATE TABLE IF NOT EXISTS "EVENT" (
"EVENT_ID" integer primary key autoincrement,
"CLUSTER_REF" integer,
"PACKAGE_REF" integer,
"CODE" integer,
"MANUFACTURER_CODE" integer,
"NAME" text,
"DESCRIPTION" text,
"SIDE" text,
"IS_OPTIONAL" integer,
"IS_FABRIC_SENSITIVE" integer,
"PRIORITY" text,
"INTRODUCED_IN_REF" integer,
"REMOVED_IN_REF" integer,
foreign key (CLUSTER_REF) references CLUSTER(CLUSTER_ID) ON DELETE CASCADE ON UPDATE CASCADE,
foreign key (PACKAGE_REF) references PACKAGE(PACKAGE_ID) ON DELETE CASCADE ON UPDATE CASCADE,
foreign key (INTRODUCED_IN_REF) references SPEC(SPEC_ID) ON DELETE CASCADE ON UPDATE CASCADE,
foreign key (REMOVED_IN_REF) references SPEC(SPEC_ID) ON DELETE CASCADE ON UPDATE CASCADE
UNIQUE(CLUSTER_REF, PACKAGE_REF, CODE, MANUFACTURER_CODE)
);
/*
EVENT_FIELD table contains events for a given cluster.
*/
DROP TABLE IF EXISTS "EVENT_FIELD";
CREATE TABLE IF NOT EXISTS "EVENT_FIELD" (
"EVENT_REF" integer,
"FIELD_IDENTIFIER" integer,
"NAME" text,
"TYPE" text,
"IS_ARRAY" integer,
"IS_NULLABLE" integer,
"IS_OPTIONAL" integer,
"INTRODUCED_IN_REF" integer,
"REMOVED_IN_REF" integer,
foreign key (INTRODUCED_IN_REF) references SPEC(SPEC_ID) ON DELETE CASCADE ON UPDATE CASCADE,
foreign key (REMOVED_IN_REF) references SPEC(SPEC_ID) ON DELETE CASCADE ON UPDATE CASCADE,
foreign key (EVENT_REF) references EVENT(EVENT_ID) ON DELETE CASCADE ON UPDATE CASCADE
UNIQUE(EVENT_REF, FIELD_IDENTIFIER)
);
/*
ATTRIBUTE table contains attributes for the cluster.
*/
DROP TABLE IF EXISTS "ATTRIBUTE";
CREATE TABLE IF NOT EXISTS "ATTRIBUTE" (
"ATTRIBUTE_ID" integer primary key autoincrement,
"CLUSTER_REF" integer,
"PACKAGE_REF" integer,
"CODE" integer,
"MANUFACTURER_CODE" integer,
"NAME" text,
"TYPE" text,
"SIDE" text,
"DEFINE" text,
"MIN" text,
"MAX" text,
"MIN_LENGTH" integer,
"MAX_LENGTH" integer,
"REPORT_MIN_INTERVAL" integer,
"REPORT_MAX_INTERVAL" integer,
"REPORTABLE_CHANGE" text,
"REPORTABLE_CHANGE_LENGTH" integer,
"IS_WRITABLE" integer,
"DEFAULT_VALUE" text,
"IS_SCENE_REQUIRED" integer,
"IS_OPTIONAL" integer,
"REPORTING_POLICY" text,
"STORAGE_POLICY" text,
"IS_NULLABLE" integer,
"ARRAY_TYPE" text,
"MUST_USE_TIMED_WRITE" integer,
"INTRODUCED_IN_REF" integer,
"REMOVED_IN_REF" integer,
"API_MATURITY" text,
"IS_CHANGE_COMITTED" integer,
"PERSISTENCE" text,
foreign key (INTRODUCED_IN_REF) references SPEC(SPEC_ID) ON DELETE CASCADE ON UPDATE CASCADE,
foreign key (REMOVED_IN_REF) references SPEC(SPEC_ID) ON DELETE CASCADE ON UPDATE CASCADE,
foreign key (CLUSTER_REF) references CLUSTER(CLUSTER_ID) ON DELETE CASCADE ON UPDATE CASCADE,
foreign key (PACKAGE_REF) references PACKAGE(PACKAGE_ID) ON DELETE CASCADE ON UPDATE CASCADE
UNIQUE("CLUSTER_REF", "PACKAGE_REF", "CODE", "MANUFACTURER_CODE")
);
/*
ATTRIBUTE MAPPING table contains associated attribute references.
*/
DROP TABLE IF EXISTS "ATTRIBUTE_MAPPING";
CREATE TABLE IF NOT EXISTS "ATTRIBUTE_MAPPING" (
"ATTRIBUTE_MAPPING_ID" integer primary key autoincrement,
"ATTRIBUTE_LEFT_REF" integer,
"ATTRIBUTE_RIGHT_REF" integer,
foreign key (ATTRIBUTE_LEFT_REF) references ATTRIBUTE(ATTRIBUTE_ID) ON DELETE CASCADE ON UPDATE CASCADE,
foreign key (ATTRIBUTE_RIGHT_REF) references ATTRIBUTE(ATTRIBUTE_ID) ON DELETE CASCADE ON UPDATE CASCADE
UNIQUE("ATTRIBUTE_LEFT_REF", "ATTRIBUTE_RIGHT_REF")
);
/*
GLOBAL_ATTRIBUTE_DEFAULT table contains default values of attributes per cluster.
Note that for the regular attribute defaults are already provided in DEFAULT_VALUE
column in ATTRIBUTE table. The only place where this is needed is for the global
attributes, which have CLUSTER_REF set to null in attribute table, so you need
a per-cluster space for different default values.
If a certain cluster/attribute combination does not exist in this table, the value
should be table from ATTRIBUTE table directly.
*/
DROP TABLE IF EXISTS "GLOBAL_ATTRIBUTE_DEFAULT";
CREATE TABLE IF NOT EXISTS "GLOBAL_ATTRIBUTE_DEFAULT" (
"GLOBAL_ATTRIBUTE_DEFAULT_ID" integer primary key autoincrement,
"CLUSTER_REF" integer NOT NULL,
"ATTRIBUTE_REF" integer NOT NULL,
"DEFAULT_VALUE" text,
foreign key(CLUSTER_REF) references CLUSTER(CLUSTER_ID) ON DELETE CASCADE ON UPDATE CASCADE,
foreign key(ATTRIBUTE_REF) references ATTRIBUTE(ATTRIBUTE_ID) ON DELETE CASCADE ON UPDATE CASCADE
UNIQUE(CLUSTER_REF, ATTRIBUTE_REF)
);
/*
GLOBAL_ATTRIBUTE_BIT is carrying information about the mappings of a
bit for a given global attribute value. Example are FeatureMap global
attributes in Matter implementation. For that case, the value
of global attribute carries both the value, as well as the meaning
of which bit corresponds to whith TAG. Hence this separate table that
links those.
*/
DROP TABLE IF EXISTS "GLOBAL_ATTRIBUTE_BIT";
CREATE TABLE IF NOT EXISTS "GLOBAL_ATTRIBUTE_BIT" (
"GLOBAL_ATTRIBUTE_DEFAULT_REF" integer NOT NULL,
"BIT" integer NOT NULL,
"VALUE" integer,
"TAG_REF" integer NOT NULL,
foreign key(GLOBAL_ATTRIBUTE_DEFAULT_REF) references GLOBAL_ATTRIBUTE_DEFAULT(GLOBAL_ATTRIBUTE_DEFAULT_ID) ON DELETE CASCADE ON UPDATE CASCADE,
foreign key(TAG_REF) references TAG(TAG_ID) ON DELETE CASCADE ON UPDATE CASCADE
UNIQUE(GLOBAL_ATTRIBUTE_DEFAULT_REF, TAG_REF, BIT)
);
/*
DEVICE_TYPE table contains device types directly loaded from packages.
*/
DROP TABLE IF EXISTS "DEVICE_TYPE";
CREATE TABLE IF NOT EXISTS "DEVICE_TYPE" (
"DEVICE_TYPE_ID" integer primary key autoincrement,
"PACKAGE_REF" integer,
"DOMAIN" text,
"CODE" integer,
"PROFILE_ID" integer,
"NAME" text,
"DESCRIPTION" text,
"CLASS" text,
"SCOPE" text,
"SUPERSET" text,
foreign key (PACKAGE_REF) references PACKAGE(PACKAGE_ID) ON DELETE CASCADE ON UPDATE CASCADE
);
/*
This table stores information about endpoint compositions.
Each record represents a composition associated with a specific device type.
Columns:
ENDPOINT_COMPOSITION_ID: The primary key of the table, auto-incremented for each new record.
DEVICE_TYPE_REF: A foreign key linking to the DEVICE_TYPE table, indicating the device type associated with this composition.
TYPE: A text field describing the type of the endpoint composition.
CODE: An integer representing a unique code for the endpoint composition.
Foreign Key Constraints:
The DEVICE_TYPE_REF column references the DEVICE_TYPE_ID column of the DEVICE_TYPE table.
On deletion of a referenced device type, corresponding records in this table are deleted (CASCADE).
*/
CREATE TABLE IF NOT EXISTS "ENDPOINT_COMPOSITION" (
"ENDPOINT_COMPOSITION_ID" integer PRIMARY KEY AUTOINCREMENT,
"DEVICE_TYPE_REF" integer,
"TYPE" text,
"CODE" integer,
FOREIGN KEY ("DEVICE_TYPE_REF") REFERENCES "DEVICE_TYPE"("DEVICE_TYPE_ID") ON DELETE CASCADE
);
/*
This table defines the composition of devices within the system.
It links devices to their types and endpoint compositions, specifying their conformance and constraints.
Columns:
DEVICE_COMPOSITION_ID: The primary key of the table, auto-incremented for each new record.
CODE: An integer representing the device code.
DEVICE_TYPE_REF: An integer that acts as a foreign key to reference a specific device type.
ENDPOINT_COMPOSITION_REF: A foreign key linking to the ENDPOINT_COMPOSITION table to specify the endpoint composition associated with this device.
CONFORMANCE: A text field describing the conformance level of the device composition.
DEVICE_CONSTRAINT: An integer representing any constraints applied to the device composition.
Foreign Key Constraints:
The DEVICE_TYPE_REF column references the DEVICE_TYPE_ID column of the DEVICE_TYPE table. On deletion of a device type, corresponding records in this table are deleted (CASCADE).
The ENDPOINT_COMPOSITION_REF column references the ENDPOINT_COMPOSITION_ID column of the ENDPOINT_COMPOSITION table. On deletion of an endpoint composition, corresponding records in this table are deleted (CASCADE).
*/
CREATE TABLE IF NOT EXISTS "DEVICE_COMPOSITION" (
"DEVICE_COMPOSITION_ID" integer PRIMARY KEY AUTOINCREMENT,
"CODE" integer,
"DEVICE_TYPE_REF" integer,
"ENDPOINT_COMPOSITION_REF" integer,
"CONFORMANCE" text,
"DEVICE_CONSTRAINT" integer,
FOREIGN KEY ("ENDPOINT_COMPOSITION_REF") REFERENCES "ENDPOINT_COMPOSITION"("ENDPOINT_COMPOSITION_ID") ON DELETE CASCADE
FOREIGN KEY ("DEVICE_TYPE_REF") REFERENCES "DEVICE_TYPE"("DEVICE_TYPE_ID") ON DELETE CASCADE
);
/*
DEVICE_TYPE_CLUSTER contains clusters that belong to the device type.
*/
DROP TABLE IF EXISTS "DEVICE_TYPE_CLUSTER";
CREATE TABLE IF NOT EXISTS "DEVICE_TYPE_CLUSTER" (
"DEVICE_TYPE_CLUSTER_ID" integer primary key autoincrement,
"DEVICE_TYPE_REF" integer,
"CLUSTER_REF" integer,
"CLUSTER_NAME" text,
"INCLUDE_CLIENT" integer,
"INCLUDE_SERVER" integer,
"LOCK_CLIENT" integer,
"LOCK_SERVER" integer,
foreign key (DEVICE_TYPE_REF) references DEVICE_TYPE(DEVICE_TYPE_ID) ON DELETE CASCADE ON UPDATE CASCADE,
foreign key (CLUSTER_REF) references CLUSTER(CLUSTER_ID) ON DELETE CASCADE ON UPDATE CASCADE
);
/*
DEVICE_TYPE_FEATURE is the junction table between device type and feature
tables.
*/
DROP TABLE IF EXISTS "DEVICE_TYPE_FEATURE";
CREATE TABLE IF NOT EXISTS "DEVICE_TYPE_FEATURE" (
"DEVICE_TYPE_CLUSTER_REF" integer,
"FEATURE_REF" integer,
"FEATURE_CODE" text,
foreign key (DEVICE_TYPE_CLUSTER_REF) references DEVICE_TYPE_CLUSTER(DEVICE_TYPE_CLUSTER_ID) ON DELETE CASCADE ON UPDATE CASCADE,
foreign key (FEATURE_REF) references FEATURE(FEATURE_ID) ON DELETE CASCADE ON UPDATE CASCADE
UNIQUE(DEVICE_TYPE_CLUSTER_REF, FEATURE_REF)
);
/*
FEATURE contains feature information
*/
DROP TABLE IF EXISTS "FEATURE";
CREATE TABLE IF NOT EXISTS "FEATURE" (
"FEATURE_ID" integer primary key autoincrement,
"NAME" text,
"CODE" text,
"BIT" integer,
"DEFAULT_VALUE" integer,
"DESCRIPTION" text,
"CONFORMANCE" text,
"PACKAGE_REF" integer,
"CLUSTER_REF" integer,
foreign key(PACKAGE_REF) references PACKAGE(PACKAGE_ID) ON DELETE CASCADE ON UPDATE CASCADE,
foreign key(CLUSTER_REF) references CLUSTER(CLUSTER_ID) ON DELETE CASCADE ON UPDATE CASCADE
UNIQUE(CODE, BIT, PACKAGE_REF, CLUSTER_REF)
);
/*
DEVICE_TYPE_ATTRIBUTE contains attribuets that belong to a device type cluster.
*/
DROP TABLE IF EXISTS "DEVICE_TYPE_ATTRIBUTE";
CREATE TABLE IF NOT EXISTS "DEVICE_TYPE_ATTRIBUTE" (
"DEVICE_TYPE_CLUSTER_REF" integer,
"ATTRIBUTE_REF" integer,
"ATTRIBUTE_NAME" text,
foreign key (DEVICE_TYPE_CLUSTER_REF) references DEVICE_TYPE_CLUSTER(DEVICE_TYPE_CLUSTER_ID) ON DELETE CASCADE ON UPDATE CASCADE,
foreign key (ATTRIBUTE_REF) references ATTRIBUTE(ATTRIBUTE_ID) ON DELETE CASCADE ON UPDATE CASCADE
);
/*
DEVICE_TYPE_COMMAND contains attributes that belong to a device type cluster.
*/
DROP TABLE IF EXISTS "DEVICE_TYPE_COMMAND";
CREATE TABLE IF NOT EXISTS "DEVICE_TYPE_COMMAND" (
"DEVICE_TYPE_CLUSTER_REF" integer,
"COMMAND_REF" integer,
"COMMAND_NAME" text,
foreign key (DEVICE_TYPE_CLUSTER_REF) references DEVICE_TYPE_CLUSTER(DEVICE_TYPE_CLUSTER_ID) ON DELETE CASCADE ON UPDATE CASCADE,
foreign key (COMMAND_REF) references COMMAND(COMMAND_ID) ON DELETE CASCADE ON UPDATE CASCADE
);
/*
TAG table contains tags. They can be used for access control and feature maps.
*/
DROP TABLE IF EXISTS "TAG";
CREATE TABLE IF NOT EXISTS "TAG" (
"TAG_ID" integer primary key autoincrement,
"PACKAGE_REF" integer,
"CLUSTER_REF" integer,
"NAME" text,
"DESCRIPTION" text,
foreign key (PACKAGE_REF) references PACKAGE(PACKAGE_ID) ON DELETE CASCADE ON UPDATE CASCADE,
foreign key (CLUSTER_REF) references CLUSTER(CLUSTER_ID) ON DELETE CASCADE ON UPDATE CASCADE
UNIQUE(PACKAGE_REF, CLUSTER_REF, NAME)
);
/*
*
* $$$$$$$$\
* \__$$ __|
* $$ |$$\ $$\ $$$$$$\ $$$$$$\ $$$$$$$\
* $$ |$$ | $$ |$$ __$$\ $$ __$$\ $$ _____|
* $$ |$$ | $$ |$$ / $$ |$$$$$$$$ |\$$$$$$\
* $$ |$$ | $$ |$$ | $$ |$$ ____| \____$$\
* $$ |\$$$$$$$ |$$$$$$$ |\$$$$$$$\ $$$$$$$ |
* \__| \____$$ |$$ ____/ \_______|\_______/
* $$\ $$ |$$ |
* \$$$$$$ |$$ |
* \______/ \__|
*/
/*
DISCRIMINATOR table contains the data types loaded from packages
*/
DROP TABLE IF EXISTS "DISCRIMINATOR";
CREATE TABLE IF NOT EXISTS "DISCRIMINATOR" (
"DISCRIMINATOR_ID" integer NOT NULL PRIMARY KEY autoincrement,
"NAME" text,
"PACKAGE_REF" integer,
FOREIGN KEY (PACKAGE_REF) REFERENCES PACKAGE(PACKAGE_ID) ON DELETE CASCADE ON UPDATE CASCADE,
CONSTRAINT DISCRIMINATOR_INFO UNIQUE("NAME", "PACKAGE_REF")
);
/*
DATA_TYPE table contains the all data types loaded from packages
*/
DROP TABLE IF EXISTS "DATA_TYPE";
CREATE TABLE IF NOT EXISTS "DATA_TYPE" (
"DATA_TYPE_ID" integer NOT NULL PRIMARY KEY autoincrement,
"NAME" text,
"DESCRIPTION" text,
"DISCRIMINATOR_REF" integer,
"PACKAGE_REF" integer,
FOREIGN KEY (DISCRIMINATOR_REF) REFERENCES DISCRIMINATOR(DISCRIMINATOR_ID) ON DELETE CASCADE ON UPDATE CASCADE,
FOREIGN KEY (PACKAGE_REF) REFERENCES PACKAGE(PACKAGE_ID) ON DELETE CASCADE ON UPDATE CASCADE
);
/*
DATA_TYPE_CLUSTER table is a junction table between the data types and clusters.
This table stores the information on which data types are shared across clusters
Note: The reason for having cluster code in this table is to load the Cluster
reference during post loading. In terms of the schema an exception was made for
loading cluster references into this table. For eg: See processZclPostLoading
*/
DROP TABLE IF EXISTS DATA_TYPE_CLUSTER;
CREATE TABLE DATA_TYPE_CLUSTER (
DATA_TYPE_CLUSTER_ID integer NOT NULL PRIMARY KEY autoincrement,
CLUSTER_REF integer,
CLUSTER_CODE integer,
DATA_TYPE_REF integer,
FOREIGN KEY (CLUSTER_REF) REFERENCES CLUSTER(CLUSTER_ID) ON DELETE CASCADE ON UPDATE CASCADE,
FOREIGN KEY (DATA_TYPE_REF) REFERENCES DATA_TYPE(DATA_TYPE_ID) ON DELETE CASCADE ON UPDATE CASCADE,
UNIQUE(CLUSTER_REF, DATA_TYPE_REF)
);
/*
NUMBER table contains the all numbers loaded from packages
*/
DROP TABLE IF EXISTS "NUMBER";
CREATE TABLE NUMBER (
NUMBER_ID integer NOT NULL PRIMARY KEY,
SIZE integer,
IS_SIGNED integer,
FOREIGN KEY (NUMBER_ID) REFERENCES DATA_TYPE(DATA_TYPE_ID) ON DELETE CASCADE ON UPDATE CASCADE
);
/*
STRING table contains the all strings loaded from packages
*/
DROP TABLE IF EXISTS "STRING";
CREATE TABLE STRING (
STRING_ID integer NOT NULL PRIMARY KEY,
IS_LONG integer,
SIZE integer,
IS_CHAR integer,
FOREIGN KEY (STRING_ID) REFERENCES DATA_TYPE(DATA_TYPE_ID) ON DELETE CASCADE ON UPDATE CASCADE
);
/*
ATOMIC table contains the atomic types loaded from packages
*/
DROP TABLE IF EXISTS "ATOMIC";
CREATE TABLE IF NOT EXISTS "ATOMIC" (
"ATOMIC_ID" integer primary key autoincrement,
"PACKAGE_REF" integer,
"NAME" text,
"DESCRIPTION" text,
"ATOMIC_IDENTIFIER" integer,
"ATOMIC_SIZE" integer,
"IS_DISCRETE" integer default false,
"IS_STRING" integer default false,
"IS_LONG" integer default false,
"IS_CHAR" integer default false,
"IS_SIGNED" integer default false,
foreign key (PACKAGE_REF) references PACKAGE(PACKAGE_ID) ON DELETE CASCADE ON UPDATE CASCADE
UNIQUE(PACKAGE_REF, NAME, ATOMIC_IDENTIFIER)
);
/*
BITMAP table contains the bitmaps directly loaded from packages.
*/
DROP TABLE IF EXISTS "BITMAP";
CREATE TABLE IF NOT EXISTS BITMAP (
BITMAP_ID integer NOT NULL PRIMARY KEY,
SIZE integer,
FOREIGN KEY (BITMAP_ID) REFERENCES DATA_TYPE(DATA_TYPE_ID) ON DELETE CASCADE ON UPDATE CASCADE
);
/*
BITMAP_FIELD contains items that make up a bitmap.
*/
DROP TABLE IF EXISTS "BITMAP_FIELD";
CREATE TABLE IF NOT EXISTS BITMAP_FIELD (
BITMAP_FIELD_ID integer NOT NULL PRIMARY KEY autoincrement,
BITMAP_REF integer,
FIELD_IDENTIFIER integer,
NAME text(100),
MASK integer,
TYPE text(100),
FOREIGN KEY (BITMAP_REF) REFERENCES BITMAP(BITMAP_ID) ON DELETE CASCADE ON UPDATE CASCADE
UNIQUE(BITMAP_REF, FIELD_IDENTIFIER)
);
/*
ENUM table contains enums directly loaded from packages.
*/
DROP TABLE IF EXISTS "ENUM";
CREATE TABLE IF NOT EXISTS "ENUM" (
ENUM_ID integer NOT NULL PRIMARY KEY,
SIZE integer,
FOREIGN KEY (ENUM_ID) REFERENCES DATA_TYPE(DATA_TYPE_ID) ON DELETE CASCADE ON UPDATE CASCADE
);
/*
ENUM_ITEM table contains individual enum items.
*/
DROP TABLE IF EXISTS "ENUM_ITEM";
CREATE TABLE IF NOT EXISTS "ENUM_ITEM" (
"ENUM_ITEM_ID" integer NOT NULL PRIMARY KEY autoincrement,
"ENUM_REF" integer,
"NAME" text,
"DESCRIPTION" text,
"FIELD_IDENTIFIER" integer,
"VALUE" integer,
FOREIGN KEY (ENUM_REF) REFERENCES "ENUM"(ENUM_ID) ON DELETE CASCADE ON UPDATE CASCADE
UNIQUE(ENUM_REF, FIELD_IDENTIFIER)
);
/*
STRUCT table contains structs directly loaded from packages.
*/
DROP TABLE IF EXISTS "STRUCT";
CREATE TABLE IF NOT EXISTS STRUCT (
STRUCT_ID integer NOT NULL PRIMARY KEY,
IS_FABRIC_SCOPED integer,
SIZE integer,
API_MATURITY text,
FOREIGN KEY (STRUCT_ID) REFERENCES DATA_TYPE(DATA_TYPE_ID) ON DELETE CASCADE ON UPDATE CASCADE
);
/*
STRUCT_ITEM table contains individual struct items.
*/
DROP TABLE IF EXISTS "STRUCT_ITEM";
CREATE TABLE IF NOT EXISTS STRUCT_ITEM (
STRUCT_ITEM_ID integer NOT NULL PRIMARY KEY autoincrement,
STRUCT_REF integer,
FIELD_IDENTIFIER integer,
NAME text(100),
IS_ARRAY integer,
IS_ENUM integer,
MIN_LENGTH integer,
MAX_LENGTH integer,
IS_WRITABLE integer,
IS_NULLABLE integer,
IS_OPTIONAL integer,
IS_FABRIC_SENSITIVE integer,
SIZE integer,
DATA_TYPE_REF integer NOT NULL,
FOREIGN KEY (STRUCT_REF) REFERENCES STRUCT(STRUCT_ID) ON DELETE CASCADE ON UPDATE CASCADE,
FOREIGN KEY (DATA_TYPE_REF) REFERENCES DATA_TYPE(DATA_TYPE_ID) ON DELETE CASCADE ON UPDATE CASCADE
UNIQUE(STRUCT_REF, FIELD_IDENTIFIER)
);
/*
* $$$$$$\
* $$ __$$\
* $$ / $$ | $$$$$$$\ $$$$$$$\ $$$$$$\ $$$$$$$\ $$$$$$$\
* $$$$$$$$ |$$ _____|$$ _____|$$ __$$\ $$ _____|$$ _____|
* $$ __$$ |$$ / $$ / $$$$$$$$ |\$$$$$$\ \$$$$$$\
* $$ | $$ |$$ | $$ | $$ ____| \____$$\ \____$$\
* $$ | $$ |\$$$$$$$\ \$$$$$$$\ \$$$$$$$\ $$$$$$$ |$$$$$$$ |
* \__| \__| \_______| \_______| \_______|\_______/ \_______/
*/
DROP TABLE IF EXISTS "OPERATION";
CREATE TABLE IF NOT EXISTS "OPERATION" (
"OPERATION_ID" integer primary key autoincrement,
"PACKAGE_REF" integer,
"NAME" text,
"DESCRIPTION" text,
foreign key (PACKAGE_REF) references PACKAGE(PACKAGE_ID) ON DELETE CASCADE ON UPDATE CASCADE
UNIQUE(PACKAGE_REF, NAME)
);
DROP TABLE IF EXISTS "ROLE";
CREATE TABLE IF NOT EXISTS "ROLE" (
"ROLE_ID" integer primary key autoincrement,
"PACKAGE_REF" integer,
"LEVEL" integer,
"NAME" text,
"DESCRIPTION" text,
foreign key (PACKAGE_REF) references PACKAGE(PACKAGE_ID) ON DELETE CASCADE ON UPDATE CASCADE
UNIQUE(PACKAGE_REF, NAME)
);
DROP TABLE IF EXISTS "ACCESS_MODIFIER";
CREATE TABLE IF NOT EXISTS "ACCESS_MODIFIER" (
"ACCESS_MODIFIER_ID" integer primary key autoincrement,
"PACKAGE_REF" integer,
"NAME" text,
"DESCRIPTION" text,
foreign key (PACKAGE_REF) references PACKAGE(PACKAGE_ID) ON DELETE CASCADE ON UPDATE CASCADE
UNIQUE(PACKAGE_REF, NAME)
);
DROP TABLE IF EXISTS "ACCESS";
CREATE TABLE IF NOT EXISTS "ACCESS" (
"ACCESS_ID" integer primary key autoincrement,
"OPERATION_REF" integer,
"ROLE_REF" integer,
"ACCESS_MODIFIER_REF" integer,
foreign key (OPERATION_REF) references OPERATION(OPERATION_ID) ON DELETE CASCADE ON UPDATE CASCADE,
foreign key (ROLE_REF) references ROLE(ROLE_ID) ON DELETE CASCADE ON UPDATE CASCADE,
foreign key (ACCESS_MODIFIER_REF) references ACCESS_MODIFIER(ACCESS_MODIFIER_ID) ON DELETE CASCADE ON UPDATE CASCADE
);
DROP TABLE IF EXISTS "CLUSTER_ACCESS";
CREATE TABLE IF NOT EXISTS "CLUSTER_ACCESS" (
"CLUSTER_REF" integer,
"ACCESS_REF" integer,
foreign key(ACCESS_REF) references ACCESS(ACCESS_ID) ON DELETE CASCADE ON UPDATE CASCADE,
foreign key(CLUSTER_REF) references CLUSTER(CLUSTER_ID) ON DELETE CASCADE ON UPDATE CASCADE
UNIQUE(CLUSTER_REF, ACCESS_REF)
);
DROP TABLE IF EXISTS "ATTRIBUTE_ACCESS";
CREATE TABLE IF NOT EXISTS "ATTRIBUTE_ACCESS" (
"ATTRIBUTE_REF" integer,
"ACCESS_REF" integer,
foreign key(ACCESS_REF) references ACCESS(ACCESS_ID) ON DELETE CASCADE ON UPDATE CASCADE,
foreign key(ATTRIBUTE_REF) references ATTRIBUTE(ATTRIBUTE_ID) ON DELETE CASCADE ON UPDATE CASCADE
UNIQUE(ATTRIBUTE_REF, ACCESS_REF)
);
DROP TABLE IF EXISTS "COMMAND_ACCESS";
CREATE TABLE IF NOT EXISTS "COMMAND_ACCESS" (
"COMMAND_REF" integer,
"ACCESS_REF" integer,
foreign key(ACCESS_REF) references ACCESS(ACCESS_ID) ON DELETE CASCADE ON UPDATE CASCADE,
foreign key(COMMAND_REF) references COMMAND(COMMAND_ID) ON DELETE CASCADE ON UPDATE CASCADE
UNIQUE(COMMAND_REF, ACCESS_REF)
);
DROP TABLE IF EXISTS "EVENT_ACCESS";
CREATE TABLE IF NOT EXISTS "EVENT_ACCESS" (
"EVENT_REF" integer,
"ACCESS_REF" integer,
foreign key(ACCESS_REF) references ACCESS(ACCESS_ID) ON DELETE CASCADE ON UPDATE CASCADE,
foreign key(EVENT_REF) references EVENT(EVENT_ID) ON DELETE CASCADE ON UPDATE CASCADE
UNIQUE(EVENT_REF, ACCESS_REF)
);
DROP TABLE IF EXISTS "DEFAULT_ACCESS";
CREATE TABLE IF NOT EXISTS "DEFAULT_ACCESS" (
"PACKAGE_REF" integer,
"ENTITY_TYPE" text,
"ACCESS_REF" integer,
foreign key(ACCESS_REF) references ACCESS(ACCESS_ID) ON DELETE CASCADE ON UPDATE CASCADE,
foreign key (PACKAGE_REF) references PACKAGE(PACKAGE_ID) ON DELETE CASCADE ON UPDATE CASCADE
UNIQUE(PACKAGE_REF, ACCESS_REF)
);
/*
*
* $$$$$$\ $$\ $$\ $$\
* $$ __$$\ \__| $$ | $$ |
* $$ / \__| $$$$$$\ $$$$$$$\ $$$$$$$\ $$\ $$$$$$\ $$$$$$$\ $$$$$$$ | $$$$$$\ $$$$$$\ $$$$$$\
* \$$$$$$\ $$ __$$\ $$ _____|$$ _____|$$ |$$ __$$\ $$ __$$\ $$ __$$ | \____$$\\_$$ _| \____$$\
* \____$$\ $$$$$$$$ |\$$$$$$\ \$$$$$$\ $$ |$$ / $$ |$$ | $$ | $$ / $$ | $$$$$$$ | $$ | $$$$$$$ |
* $$\ $$ |$$ ____| \____$$\ \____$$\ $$ |$$ | $$ |$$ | $$ | $$ | $$ |$$ __$$ | $$ |$$\ $$ __$$ |
* \$$$$$$ |\$$$$$$$\ $$$$$$$ |$$$$$$$ |$$ |\$$$$$$ |$$ | $$ | \$$$$$$$ |\$$$$$$$ | \$$$$ |\$$$$$$$ |
* \______/ \_______|\_______/ \_______/ \__| \______/ \__| \__| \_______| \_______| \____/ \_______|
*/
/*
USER table contains a reference to a single "user", which really refers to a given cookie on the
browser side. There is no login management here, so this just refers to a unique browser instance.
*/
DROP TABLE IF EXISTS "USER";
CREATE TABLE IF NOT EXISTS "USER" (
"USER_ID" integer primary key autoincrement,
"USER_KEY" text,
"CREATION_TIME" integer,
UNIQUE(USER_KEY)
);
/*
SESSION table contains the list of known and remembered sessions.
In case of electron SESSION_WINID is the window ID for a given
session.
*/
DROP TABLE IF EXISTS "SESSION";
CREATE TABLE IF NOT EXISTS "SESSION" (
"SESSION_ID" integer primary key autoincrement,
"USER_REF" integer,
"SESSION_KEY" text,
"CREATION_TIME" integer,
"DIRTY" integer default 1,
"NEW_NOTIFICATION" integer default 0,
foreign key (USER_REF) references USER(USER_ID) ON DELETE CASCADE ON UPDATE CASCADE,
UNIQUE(SESSION_KEY)
);
/*
SESSION_KEY_VALUE table contains the data points that are simple
key/value pairs.
*/
DROP TABLE IF EXISTS "SESSION_KEY_VALUE";
CREATE TABLE IF NOT EXISTS "SESSION_KEY_VALUE" (
"SESSION_REF" integer,
"KEY" text,
"VALUE" text,
foreign key (SESSION_REF) references SESSION(SESSION_ID) ON DELETE CASCADE ON UPDATE CASCADE,
UNIQUE(SESSION_REF, KEY)
);
/*
SESSION_LOG table contains general purpose text log for the session
*/
DROP TABLE IF EXISTS "SESSION_LOG";
CREATE TABLE IF NOT EXISTS "SESSION_LOG" (
"SESSION_REF" integer,
"TIMESTAMP" text,
"LOG" text,
foreign key (SESSION_REF) references SESSION(SESSION_ID) ON DELETE CASCADE ON UPDATE CASCADE
UNIQUE(SESSION_REF, TIMESTAMP, LOG)
);
DROP TABLE IF EXISTS "SESSION_PARTITION";
CREATE TABLE IF NOT EXISTS "SESSION_PARTITION" (
"SESSION_PARTITION_ID" integer primary key autoincrement,
"SESSION_PARTITION_NUMBER" integer,
"SESSION_REF" integer,
foreign key (SESSION_REF) references SESSION(SESSION_ID) ON DELETE CASCADE ON UPDATE CASCADE
UNIQUE(SESSION_PARTITION_NUMBER, SESSION_REF)
);
/*
SESSION_PACKAGE table is a junction table, listing which packages
are used for a given session.
*/
DROP TABLE IF EXISTS "SESSION_PACKAGE";
CREATE TABLE IF NOT EXISTS "SESSION_PACKAGE" (
"SESSION_PARTITION_REF" integer,
"PACKAGE_REF" integer,
"REQUIRED" integer default false,
"ENABLED" integer default true,
foreign key (SESSION_PARTITION_REF) references SESSION_PARTITION(SESSION_PARTITION_ID) ON DELETE CASCADE ON UPDATE CASCADE,
foreign key (PACKAGE_REF) references PACKAGE(PACKAGE_ID) ON DELETE CASCADE ON UPDATE CASCADE,
UNIQUE(SESSION_PARTITION_REF, PACKAGE_REF)
);
/*
ENDPOINT_TYPE contains the bulk of the configuration: clusters, attributes, etc.
*/
DROP TABLE IF EXISTS "ENDPOINT_TYPE";
CREATE TABLE IF NOT EXISTS "ENDPOINT_TYPE" (
"ENDPOINT_TYPE_ID" integer primary key autoincrement,
"SESSION_PARTITION_REF" integer,
"NAME" text,
foreign key (SESSION_PARTITION_REF) references SESSION_PARTITION(SESSION_PARTITION_ID) ON DELETE CASCADE ON UPDATE CASCADE
);
/*
ENDPOINT_TYPE_DEVICE: many-to-many relationship between endpoint type and
device type.
*/
DROP TABLE IF EXISTS "ENDPOINT_TYPE_DEVICE";
CREATE TABLE IF NOT EXISTS "ENDPOINT_TYPE_DEVICE" (
"ENDPOINT_TYPE_DEVICE_ID" integer primary key autoincrement,
"DEVICE_TYPE_REF" INTEGER,
"ENDPOINT_TYPE_REF" INTEGER,
"DEVICE_TYPE_ORDER" INTEGER,
"DEVICE_IDENTIFIER" INTEGER,
"DEVICE_VERSION" INTEGER,
foreign key(DEVICE_TYPE_REF) references DEVICE_TYPE(DEVICE_TYPE_ID) ON DELETE CASCADE ON UPDATE CASCADE,
foreign key (ENDPOINT_TYPE_REF) references ENDPOINT_TYPE(ENDPOINT_TYPE_ID) on delete
set NULL ON UPDATE CASCADE,
UNIQUE("ENDPOINT_TYPE_REF", "DEVICE_TYPE_REF")
);
/**
SQL Trigger for device type triggers per endpoint.
From Matter Data Model Spec 9.2 Endpoint Composition
Each simple endpoint SHALL support only one Application device type with these exceptions:
- The endpoint MAY support additional device types which are subsets of the Application
device type (the superset).
- The endpoint MAY support additional device types (application, utility or node device types)
as defined by each additional device type.
*/
CREATE TRIGGER ENDPOINT_TYPE_SIMPLE_DEVICE_CHECK BEFORE
INSERT ON ENDPOINT_TYPE_DEVICE
WHEN (
SELECT CLASS
FROM DEVICE_TYPE
WHERE DEVICE_TYPE.DEVICE_TYPE_ID = NEW.DEVICE_TYPE_REF
) = "Simple"
AND (
(
SELECT CLASS
FROM DEVICE_TYPE
WHERE DEVICE_TYPE.DEVICE_TYPE_ID = NEW.DEVICE_TYPE_REF
) IN (
SELECT CLASS
FROM DEVICE_TYPE
INNER JOIN ENDPOINT_TYPE_DEVICE ON DEVICE_TYPE.DEVICE_TYPE_ID = ENDPOINT_TYPE_DEVICE.DEVICE_TYPE_REF
WHERE ENDPOINT_TYPE_DEVICE.ENDPOINT_TYPE_REF = NEW.ENDPOINT_TYPE_REF
)
)
AND (
(
SELECT SUPERSET
FROM DEVICE_TYPE
WHERE DEVICE_TYPE.DEVICE_TYPE_ID = NEW.DEVICE_TYPE_REF
) NOT IN (
SELECT DESCRIPTION
FROM DEVICE_TYPE
INNER JOIN ENDPOINT_TYPE_DEVICE ON DEVICE_TYPE.DEVICE_TYPE_ID = ENDPOINT_TYPE_DEVICE.DEVICE_TYPE_REF
WHERE ENDPOINT_TYPE_DEVICE.ENDPOINT_TYPE_REF = NEW.ENDPOINT_TYPE_REF
)
)
AND (
(
SELECT DESCRIPTION
FROM DEVICE_TYPE
WHERE DEVICE_TYPE.DEVICE_TYPE_ID = NEW.DEVICE_TYPE_REF
) NOT IN (
SELECT SUPERSET
FROM DEVICE_TYPE
INNER JOIN ENDPOINT_TYPE_DEVICE ON DEVICE_TYPE.DEVICE_TYPE_ID = ENDPOINT_TYPE_DEVICE.DEVICE_TYPE_REF
WHERE ENDPOINT_TYPE_DEVICE.ENDPOINT_TYPE_REF = NEW.ENDPOINT_TYPE_REF
)
) BEGIN
SELECT RAISE(
ROLLBACK,
'Simple endpoint cannot have more than one application device type'
);
END;
/*
ENDPOINT table contains the toplevel configured endpoints.
*/
DROP TABLE IF EXISTS "ENDPOINT";
CREATE TABLE IF NOT EXISTS "ENDPOINT" (
"ENDPOINT_ID" integer primary key autoincrement,
"SESSION_REF" integer,
"ENDPOINT_TYPE_REF" integer,
"PROFILE" integer,
"ENDPOINT_IDENTIFIER" integer,
"NETWORK_IDENTIFIER" integer,
"PARENT_ENDPOINT_REF" integer NULL,
foreign key (SESSION_REF) references SESSION(SESSION_ID) ON DELETE CASCADE ON UPDATE CASCADE,
foreign key (PARENT_ENDPOINT_REF) references ENDPOINT(ENDPOINT_ID) on delete set NULL ON UPDATE CASCADE,
foreign key (ENDPOINT_TYPE_REF) references ENDPOINT_TYPE(ENDPOINT_TYPE_ID) on delete
set NULL ON UPDATE CASCADE,
UNIQUE(ENDPOINT_TYPE_REF, ENDPOINT_IDENTIFIER)
);
/*
SESSION_CLUSTER contains the on/off values for cluster.
SIDE is client or server
STATE is 1 for ON and 0 for OFF.
*/
DROP TABLE IF EXISTS "ENDPOINT_TYPE_CLUSTER";
CREATE TABLE IF NOT EXISTS "ENDPOINT_TYPE_CLUSTER" (
"ENDPOINT_TYPE_CLUSTER_ID" integer primary key autoincrement,
"ENDPOINT_TYPE_REF" integer,
"CLUSTER_REF" integer,
"SIDE" text,
"ENABLED" integer default false,
foreign key (ENDPOINT_TYPE_REF) references ENDPOINT_TYPE(ENDPOINT_TYPE_ID) ON DELETE CASCADE ON UPDATE CASCADE,
foreign key (CLUSTER_REF) references CLUSTER(CLUSTER_ID) ON DELETE CASCADE ON UPDATE CASCADE,
UNIQUE(ENDPOINT_TYPE_REF, CLUSTER_REF, SIDE)
);
/*
SQL Trigger for Device Type cluster Compliance.
This trigger is used to add a warning to the notification table regarding a
cluster not enabled as per the device type specification.
*/
CREATE TRIGGER
UPDATE_TRIGGER_DEVICE_TYPE_CLUSTER_SPEC_COMPLIANCE_MESSAGE
AFTER
UPDATE ON ENDPOINT_TYPE_CLUSTER
WHEN
(
SELECT
COUNT()
FROM
ENDPOINT_TYPE_CLUSTER
INNER JOIN
ENDPOINT_TYPE_DEVICE
ON
ENDPOINT_TYPE_CLUSTER.ENDPOINT_TYPE_REF = ENDPOINT_TYPE_DEVICE.ENDPOINT_TYPE_REF
INNER JOIN
DEVICE_TYPE_CLUSTER
ON
DEVICE_TYPE_CLUSTER.DEVICE_TYPE_REF = ENDPOINT_TYPE_DEVICE.DEVICE_TYPE_REF
WHERE
ENDPOINT_TYPE_CLUSTER.CLUSTER_REF = new.CLUSTER_REF
AND
ENDPOINT_TYPE_CLUSTER.ENDPOINT_TYPE_REF = new.ENDPOINT_TYPE_REF