blob: 92388719951217910d33c978c45de4edde930843 [file] [log] [blame]
Harald Weltee72cf552016-04-28 07:18:49 +02001--modelled roughly after TS 23.008 version 13.3.0
2
3CREATE TABLE subscriber (
4 id INTEGER PRIMARY KEY,
5 -- Chapter 2.1.1.1
Neels Hofmeyrcc785f02017-02-01 17:08:56 +01006 imsi VARCHAR(15) UNIQUE NOT NULL,
Harald Weltee72cf552016-04-28 07:18:49 +02007 -- Chapter 2.1.2
Neels Hofmeyrcc785f02017-02-01 17:08:56 +01008 msisdn VARCHAR(15) UNIQUE,
Harald Weltee72cf552016-04-28 07:18:49 +02009 -- Chapter 2.2.3: Most recent / current IMEI
10 imeisv VARCHAR,
11 -- Chapter 2.4.5
12 vlr_number VARCHAR(15),
13 -- Chapter 2.4.6
14 hlr_number VARCHAR(15),
15 -- Chapter 2.4.8.1
16 sgsn_number VARCHAR(15),
17 -- Chapter 2.13.10
18 sgsn_address VARCHAR,
19 -- Chapter 2.4.8.2
20 ggsn_number VARCHAR(15),
21 -- Chapter 2.4.9.2
22 gmlc_number VARCHAR(15),
23 -- Chapter 2.4.23
24 smsc_number VARCHAR(15),
25 -- Chapter 2.4.24
26 periodic_lu_tmr INTEGER,
27 -- Chapter 2.13.115
28 periodic_rau_tau_tmr INTEGER,
29 -- Chapter 2.1.1.2: network access mode
Harald Welte61229152016-05-03 18:47:08 +020030 nam_cs BOOLEAN NOT NULL DEFAULT 1,
31 nam_ps BOOLEAN NOT NULL DEFAULT 1,
Harald Weltee72cf552016-04-28 07:18:49 +020032 -- Chapter 2.1.8
33 lmsi INTEGER,
34
Harald Welteb18f0e02016-05-05 21:03:03 +020035 -- The below purged flags might not even be stored non-volatile,
36 -- refer to TS 23.012 Chapter 3.6.1.4
Harald Weltee72cf552016-04-28 07:18:49 +020037 -- Chapter 2.7.5
Harald Welte61229152016-05-03 18:47:08 +020038 ms_purged_cs BOOLEAN NOT NULL DEFAULT 0,
Harald Weltee72cf552016-04-28 07:18:49 +020039 -- Chapter 2.7.6
Harald Welte61229152016-05-03 18:47:08 +020040 ms_purged_ps BOOLEAN NOT NULL DEFAULT 0
Harald Weltee72cf552016-04-28 07:18:49 +020041);
42
43CREATE TABLE subscriber_apn (
44 subscriber_id INTEGER, -- subscriber.id
45 apn VARCHAR(256) NOT NULL
46);
47
48-- Chapter 2.1.3
49CREATE TABLE subscriber_multi_msisdn (
50 subscriber_id INTEGER, -- subscriber.id
51 msisdn VARCHAR(15) NOT NULL
52);
53
54CREATE TABLE auc_2g (
55 subscriber_id INTEGER PRIMARY KEY, -- subscriber.id
Neels Hofmeyr8089d512017-01-30 13:49:49 +010056 algo_id_2g INTEGER NOT NULL, -- enum osmo_auth_algo value
57 ki VARCHAR(32) NOT NULL -- hex string: subscriber's secret key (128bit)
Harald Weltee72cf552016-04-28 07:18:49 +020058);
59
60CREATE TABLE auc_3g (
Neels Hofmeyr2116ce22017-01-19 15:50:59 +010061 subscriber_id INTEGER PRIMARY KEY, -- subscriber.id
Neels Hofmeyr8089d512017-01-30 13:49:49 +010062 algo_id_3g INTEGER NOT NULL, -- enum osmo_auth_algo value
63 k VARCHAR(32) NOT NULL, -- hex string: subscriber's secret key (128bit)
64 op VARCHAR(32), -- hex string: operator's secret key (128bit)
65 opc VARCHAR(32), -- hex string: derived from OP and K (128bit)
66 sqn INTEGER NOT NULL DEFAULT 0 -- sequence number of key usage
Harald Weltee72cf552016-04-28 07:18:49 +020067);
68
Harald Welte61229152016-05-03 18:47:08 +020069CREATE UNIQUE INDEX IF NOT EXISTS idx_subscr_imsi ON subscriber (imsi);
Harald Weltee72cf552016-04-28 07:18:49 +020070-- SELECT algo_id_2g, ki, algo_id_3g, k, op, opc, sqn FROM subscriber LEFT JOIN auc_2g ON auc_2g.subscriber_id = subscriber.id LEFT JOIN auc_3g ON auc_3g.subscriber_id = subscriber.id WHERE imsi = ?