osmo-hlr/sql/hlr.sql

95 lines
2.8 KiB
MySQL
Raw Normal View History

CREATE TABLE subscriber (
-- OsmoHLR's DB scheme is modelled roughly after TS 23.008 version 13.3.0
id INTEGER PRIMARY KEY,
-- Chapter 2.1.1.1
imsi VARCHAR(15) UNIQUE NOT NULL,
-- Chapter 2.1.2
msisdn VARCHAR(15) UNIQUE,
-- Chapter 2.2.3: Most recent / current IMEISV
imeisv VARCHAR,
-- Chapter 2.1.9: Most recent / current IMEI
imei VARCHAR(14),
-- Chapter 2.4.5
vlr_number VARCHAR(15),
-- Chapter 2.4.6
msc_number VARCHAR(15),
-- Chapter 2.4.8.1
sgsn_number VARCHAR(15),
-- Chapter 2.13.10
sgsn_address VARCHAR,
-- Chapter 2.4.8.2
ggsn_number VARCHAR(15),
-- Chapter 2.4.9.2
gmlc_number VARCHAR(15),
-- Chapter 2.4.23
smsc_number VARCHAR(15),
-- Chapter 2.4.24
periodic_lu_tmr INTEGER,
-- Chapter 2.13.115
periodic_rau_tau_tmr INTEGER,
-- Chapter 2.1.1.2: network access mode
nam_cs BOOLEAN NOT NULL DEFAULT 1,
nam_ps BOOLEAN NOT NULL DEFAULT 1,
-- Chapter 2.1.8
lmsi INTEGER,
-- The below purged flags might not even be stored non-volatile,
-- refer to TS 23.012 Chapter 3.6.1.4
-- Chapter 2.7.5
ms_purged_cs BOOLEAN NOT NULL DEFAULT 0,
-- Chapter 2.7.6
ms_purged_ps BOOLEAN NOT NULL DEFAULT 0,
-- Timestamp of last location update seen from subscriber
-- The value is a string which encodes a UTC timestamp in granularity of seconds.
last_lu_seen TIMESTAMP default NULL,
last_lu_seen_ps TIMESTAMP default NULL,
-- When a LU was received via a proxy, that proxy's hlr_number is stored here,
-- while vlr_number reflects the MSC on the far side of that proxy.
vlr_via_proxy VARCHAR,
sgsn_via_proxy VARCHAR
);
CREATE TABLE subscriber_apn (
subscriber_id INTEGER, -- subscriber.id
apn VARCHAR(256) NOT NULL
);
CREATE TABLE subscriber_multi_msisdn (
-- Chapter 2.1.3
subscriber_id INTEGER, -- subscriber.id
msisdn VARCHAR(15) NOT NULL
);
CREATE TABLE auc_2g (
subscriber_id INTEGER PRIMARY KEY, -- subscriber.id
algo_id_2g INTEGER NOT NULL, -- enum osmo_auth_algo value
ki VARCHAR(32) NOT NULL -- hex string: subscriber's secret key (128bit)
);
CREATE TABLE auc_3g (
subscriber_id INTEGER PRIMARY KEY, -- subscriber.id
algo_id_3g INTEGER NOT NULL, -- enum osmo_auth_algo value
k VARCHAR(64) NOT NULL, -- hex string: subscriber's secret key (128/256bit)
op VARCHAR(64), -- hex string: operator's secret key (128/256bit)
opc VARCHAR(64), -- hex string: derived from OP and K (128/256bit)
sqn INTEGER NOT NULL DEFAULT 0, -- sequence number of key usage
-- nr of index bits at lower SQN end
ind_bitlen INTEGER NOT NULL DEFAULT 5
);
db v6: determine 3G AUC IND from VLR name Each VLR requesting auth tuples should use a distinct IND pool for 3G auth. So far we tied the IND to the GSUP peer connection; MSC and SGSN were always distinct GSUP peers, they ended up using distinct INDs. However, we have implemented a GSUP proxy, so that, in a distributed setup, a remotely roaming subscriber has only one direct GSUP peer proxying for both remote MSC and SGSN. That means as soon as a subscriber roams to a different site, we would use the GSUP proxy name to determine the IND instead of the separate MSC and SGSN. The site's MSC and SGSN appear as the same client, get the same IND bucket, waste SQNs rapidly and cause auth tuple generation load. So instead of using the local client as IND, persistently keep a list of VLR names and assign a different IND to each. Use the gsup_req->source_name as indicator, which reflects the actual remote VLR's name (remote MSC or SGSN). Persist the site <-> IND assignments in the database. Add an IND test to db_test.c There was an earlier patch version that separated the IND pools by cn_domain, but it turned out to add complex semantics, while only solving one aspect of the "adjacent VLR" problem. We need a solution not only for CS vs PS, but also for 2,3G vs 4G, and for sites that are physically adjacent to each other. This patch version does not offer any automatic solution for that -- as soon as more than 2^IND_bitlen (usually 32) VLRs show up, it is the responsibility of the admin to ensure the 'ind' table in the hlr.db does not have unfortunate IND assignments. So far no VTY commands exist for that, they may be added in the future. Related: OS#4319 Change-Id: I6f0a6bbef3a27507605c3b4a0e1a89bdfd468374
2019-12-12 03:04:53 +00:00
CREATE TABLE ind (
-- 3G auth IND pool to be used for this VLR
ind INTEGER PRIMARY KEY,
-- VLR identification, usually the GSUP source_name
vlr TEXT NOT NULL,
UNIQUE (vlr)
);
CREATE UNIQUE INDEX idx_subscr_imsi ON subscriber (imsi);
-- Set HLR database schema version number
-- Note: This constant is currently duplicated in src/db.c and must be kept in sync!
PRAGMA user_version = 7;