Web design and hosting, database, cloud and social media solutions that deliver business results
  • Business Solutions
    • Robotic Process Automation
    • Bespoke Software
    • Database Services
      • Data Integration
      • Datawarehouse Services
      • Power BI
      • Server Upgrade and DBA Services
    • Web Services
      • Logo Design
      • Payment Gateways
      • Web Localisation and Translation
      • Web Site Optimisation
      • Web Site Security
      • Technical Tools
    • Cloud Services
      • Amazon Web Services
      • Google Cloud Services
      • Microsoft Azure
    • Microsoft 365
      • Enabling the Multi Factor Authentication Application
      • Office 365 DNS Settings Generator
    • IT Hardware
    • Social Media Services
  • Academy
    • Our Test Environment
    • Learning Databases
      • The Basics
      • Get Open Query
      • SQL Server Data
      • SQL Server Maintenance
      • Using SQL Server Dates
      • Using SQL Server Functions
      • Using SQL Server Pivot-Unpivot
      • Technical Tools
    • Learning Web Design
      • Building Ousia Content Management System
      • Using ASP-NET
      • Using CSS
      • Using JavaScript
    • Learning Cloud and IT Services
      • Task Scheduler Error 2147943645
      • Blocking Blank Senders
      • Requesting SSL and Generation of PFX file in OpenSSL Simple Steps
    • Using Social Media
      • Asking for a Google Review
      • Changing a Facebook account from personal to business
      • Choosing where to focus Social Media effort
      • Social Media Image Sizes
      • Using Meta Data to set Social Media Images
  • About
    • Blog
      • Building an entry level gaming machine
      • Google Core Update Jan 2020
      • Hot Chilli Internet Closure
      • How To Choose Content For Your Website Adverts Leaflets
      • Preventing Online Scam
      • Skimmers of the gig economy
      • The most annoying things about websites on the Internet
      • Top 5 websites for free Vector Graphics
    • Careers
      • Translator English-Japanese
      • Translator English-Portuguese
      • Translator English-Spanish
      • Translator English-Turkish
    • Portfolio
    • Regulatory
    • Team
      • Chester Copperpot
      • Gavin Clayton
      • Sai Gangu
      • Suneel Kumar
      • Surya Mukkamala
Deutsch (DE)English (EN-US)English (EN-GB)Español (ES)Français (FR)हिंदी (HI)italiano (IT)日本語 (JA)polski (PL)Português (PT)русский (RU)Türk (TR)中国的 (ZH)

Check ISIN format with an SQL Function

Create a function to Check the ISIN format in SQL Server

Context

Using Financial Data

This code was created as part of an import routine to cleanse data coming in from external sources, where there were all sorts of characters that shouldn't have been there.

This one checks the format of an ISIN.

This is expanded SQL code using the documentation on the Wikipedia article on the link. You will need to create the following table to hold all of the country information.

This is part of three linked articles which will check ISIN, SEDOL and CUSIP identifiers.

more: List of Country Codes

Create and populate table

CREATE TABLE SecuritiesIssuer(
SecuritiesIssuerID intIDENTITY(1,1) NOT NULL CONSTRAINT PK_SecuritiesIssuerID PRIMARY KEY,
SecuritiesIssuerShort NVARCHAR(2) NULL,
SecuritiesIssuerCountry NVARCHAR(50) NULL)
INSERT INTO SecuritiesIssuer
SELECT *
FROM (VALUES
('AF',N'AFGHANISTAN'),
('AX',N'ÅLAND ISLANDS'),
('AL',N'ALBANIA'),
('DZ',N'ALGERIA'),
('AS',N'AMERICAN SAMOA'),
('AD',N'ANDORRA'),
('AO',N'ANGOLA'),
('AI',N'ANGUILLA'),
('AQ',N'ANTARCTICA'),
('AG',N'ANTIGUA AND BARBUDA'),
('AR',N'ARGENTINA'),
('AM',N'ARMENIA'),
('AW',N'ARUBA'),
('AU',N'AUSTRALIA'),
('AT',N'AUSTRIA'),
('AZ',N'AZERBAIJAN'),
('BS',N'BAHAMAS'),
('BH',N'BAHRAIN'),
('BD',N'BANGLADESH'),
('BB',N'BARBADOS'),
('BY',N'BELARUS'),
('BE',N'BELGIUM'),
('BZ',N'BELIZE'),
('BJ',N'BENIN'),
('BM',N'BERMUDA'),
('BT',N'BHUTAN'),
('BO',N'BOLIVIA, PLURINATIONAL STATE OF'),
('BQ',N'BONAIRE, SINT EUSTATIUS AND SABA'),
('BA',N'BOSNIA AND HERZEGOVINA'),
('BW',N'BOTSWANA'),
('BV',N'BOUVET ISLAND'),
('BR',N'BRAZIL'),
('IO',N'BRITISH INDIAN OCEAN TERRITORY'),
('BN',N'BRUNEI DARUSSALAM'),
('BG',N'BULGARIA'),
('BF',N'BURKINA FASO'),
('BI',N'BURUNDI'),
('KH',N'CAMBODIA'),
('CM',N'CAMEROON'),
('CA',N'CANADA'),
('CV',N'CAPE VERDE'),
('KY',N'CAYMAN ISLANDS'),
('CF',N'CENTRAL AFRICAN REPUBLIC'),
('TD',N'CHAD'),
('CL',N'CHILE'),
('CN',N'CHINA'),
('CX',N'CHRISTMAS ISLAND'),
('CC',N'COCOS (KEELING) ISLANDS'),
('CO',N'COLOMBIA'),
('KM',N'COMOROS'),
('CG',N'CONGO'),
('CD',N'CONGO, THE DEMOCRATIC REPUBLIC OF THE'),
('CK',N'COOK ISLANDS'),
('CR',N'COSTA RICA'),
('CI',N'CÔTE D’IVOIRE'),
('HR',N'CROATIA'),
('CU',N'CUBA'),
('CW',N'CURAÇAO'),
('CY',N'CYPRUS'),
('CZ',N'CZECH REPUBLIC'),
('DK',N'DENMARK'),
('DJ',N'DJIBOUTI'),
('DM',N'DOMINICA'),
('DO',N'DOMINICAN REPUBLIC'),
('EC',N'ECUADOR'),
('EG',N'EGYPT'),
('SV',N'EL SALVADOR'),
('GQ',N'EQUATORIAL GUINEA'),
('ER',N'ERITREA'),
('EE',N'ESTONIA'),
('ET',N'ETHIOPIA'),
('FK',N'FALKLAND ISLANDS (MALVINAS)'),
('FO',N'FAROE ISLANDS'),
('FJ',N'FIJI'),
('FI',N'FINLAND'),
('FR',N'FRANCE'),
('GF',N'FRENCH GUIANA'),
('PF',N'FRENCH POLYNESIA'),
('TF',N'FRENCH SOUTHERN TERRITORIES'),
('GA',N'GABON'),
('GM',N'GAMBIA'),
('GE',N'GEORGIA'),
('DE',N'GERMANY'),
('GH',N'GHANA'),
('GI',N'GIBRALTAR'),
('GR',N'GREECE'),
('GL',N'GREENLAND'),
('GD',N'GRENADA'),
('GP',N'GUADELOUPE'),
('GU',N'GUAM'),
('GT',N'GUATEMALA'),
('GG',N'GUERNSEY'),
('GN',N'GUINEA'),
('GW',N'GUINEA-BISSAU'),
('GY',N'GUYANA'),
('HT',N'HAITI'),
('HM',N'HEARD ISLAND AND MCDONALD ISLANDS'),
('VA',N'HOLY SEE (VATICAN CITY STATE)'),
('HN',N'HONDURAS'),
('HK',N'HONG KONG'),
('HU',N'HUNGARY'),
('IS',N'ICELAND'),
('IN',N'INDIA'),
('ID',N'INDONESIA'),
('IR',N'IRAN, ISLAMIC REPUBLIC OF'),
('IQ',N'IRAQ'),
('IE',N'IRELAND'),
('IM',N'ISLE OF MAN'),
('IL',N'ISRAEL'),
('IT',N'ITALY'),
('JM',N'JAMAICA'),
('JP',N'JAPAN'),
('JE',N'JERSEY'),
('JO',N'JORDAN'),
('KZ',N'KAZAKHSTAN'),
('KE',N'KENYA'),
('KI',N'KIRIBATI'),
('KP',N'KOREA, DEMOCRATIC PEOPLE’S REPUBLIC OF'),
('KR',N'KOREA, REPUBLIC OF'),
('KW',N'KUWAIT'),
('KG',N'KYRGYZSTAN'),
('LA',N'LAO PEOPLE’S DEMOCRATIC REPUBLIC'),
('LV',N'LATVIA'),
('LB',N'LEBANON'),
('LS',N'LESOTHO'),
('LR',N'LIBERIA'),
('LY',N'LIBYA'),
('LI',N'LIECHTENSTEIN'),
('LT',N'LITHUANIA'),
('LU',N'LUXEMBOURG'),
('MO',N'MACAO'),
('MK',N'MACEDONIA, THE FORMER YUGOSLAV REPUBLIC OF'),
('MG',N'MADAGASCAR'),
('MW',N'MALAWI'),
('MY',N'MALAYSIA'),
('MV',N'MALDIVES'),
('ML',N'MALI'),
('MT',N'MALTA'),
('MH',N'MARSHALL ISLANDS'),
('MQ',N'MARTINIQUE'),
('MR',N'MAURITANIA'),
('MU',N'MAURITIUS'),
('YT',N'MAYOTTE'),
('MX',N'MEXICO'),
('FM',N'MICRONESIA, FEDERATED STATES OF'),
('MD',N'MOLDOVA, REPUBLIC OF'),
('MC',N'MONACO'),
('MN',N'MONGOLIA'),
('ME',N'MONTENEGRO'),
('MS',N'MONTSERRAT'),
('MA',N'MOROCCO'),
('MZ',N'MOZAMBIQUE'),
('MM',N'MYANMAR'),
('NA',N'NAMIBIA'),
('NR',N'NAURU'),
('NP',N'NEPAL'),
('NL',N'NETHERLANDS'),
('NC',N'NEW CALEDONIA'),
('NZ',N'NEW ZEALAND'),
('NI',N'NICARAGUA'),
('NE',N'NIGER'),
('NG',N'NIGERIA'),
('NU',N'NIUE'),
('NF',N'NORFOLK ISLAND'),
('MP',N'NORTHERN MARIANA ISLANDS'),
('NO',N'NORWAY'),
('OM',N'OMAN'),
('PK',N'PAKISTAN'),
('PW',N'PALAU'),
('PS',N'PALESTINIAN TERRITORY, OCCUPIED'),
('PA',N'PANAMA'),
('PG',N'PAPUA NEW GUINEA'),
('PY',N'PARAGUAY'),
('PE',N'PERU'),
('PH',N'PHILIPPINES'),
('PN',N'PITCAIRN'),
('PL',N'POLAND'),
('PT',N'PORTUGAL'),
('PR',N'PUERTO RICO'),
('QA',N'QATAR'),
('RE',N'RÉUNION'),
('RO',N'ROMANIA'),
('RU',N'RUSSIAN FEDERATION'),
('RW',N'RWANDA'),
('BL',N'SAINT BARTHÉLEMY'),
('SH',N'SAINT HELENA, ASCENSION AND TRISTAN DA CUNHA'),
('KN',N'SAINT KITTS AND NEVIS'),
('LC',N'SAINT LUCIA'),
('MF',N'SAINT MARTIN (FRENCH PART)'),
('PM',N'SAINT PIERRE AND MIQUELON'),
('VC',N'SAINT VINCENT AND THE GRENADINES'),
('WS',N'SAMOA'),
('SM',N'SAN MARINO'),
('ST',N'SAO TOME AND PRINCIPE'),
('SA',N'SAUDI ARABIA'),
('SN',N'SENEGAL'),
('RS',N'SERBIA'),
('SC',N'SEYCHELLES'),
('SL',N'SIERRA LEONE'),
('SG',N'SINGAPORE'),
('SX',N'SINT MAARTEN (DUTCH PART)'),
('SK',N'SLOVAKIA'),
('SI',N'SLOVENIA'),
('SB',N'SOLOMON ISLANDS'),
('SO',N'SOMALIA'),
('ZA',N'SOUTH AFRICA'),
('GS',N'SOUTH GEORGIA AND THE SOUTH SANDWICH ISLANDS'),
('SS',N'SOUTH SUDAN'),
('ES',N'SPAIN'),
('LK',N'SRI LANKA'),
('SD',N'SUDAN'),
('SR',N'SURINAME'),
('SJ',N'SVALBARD AND JAN MAYEN'),
('SZ',N'SWAZILAND'),
('SE',N'SWEDEN'),
('CH',N'SWITZERLAND'),
('SY',N'SYRIAN ARAB REPUBLIC'),
('TW',N'TAIWAN, PROVINCE OF CHINA'),
('TJ',N'TAJIKISTAN'),
('TZ',N'TANZANIA, UNITED REPUBLIC OF'),
('TH',N'THAILAND'),
('TL',N'TIMOR-LESTE'),
('TG',N'TOGO'),
('TK',N'TOKELAU'),
('TO',N'TONGA'),
('TT',N'TRINIDAD AND TOBAGO'),
('TN',N'TUNISIA'),
('TR',N'TURKEY'),
('TM',N'TURKMENISTAN'),
('TC',N'TURKS AND CAICOS ISLANDS'),
('TV',N'TUVALU'),
('UG',N'UGANDA'),
('UA',N'UKRAINE'),
('AE',N'UNITED ARAB EMIRATES'),
('GB',N'UNITED KINGDOM'),
('US',N'UNITED STATES'),
('UM',N'UNITED STATES MINOR OUTLYING ISLANDS'),
('UY',N'URUGUAY'),
('UZ',N'UZBEKISTAN'),
('VU',N'VANUATU'),
('VE',N'VENEZUELA, BOLIVARIAN REPUBLIC OF'),
('VN',N'VIET NAM'),
('VG',N'VIRGIN ISLANDS, BRITISH'),
('VI',N'VIRGIN ISLANDS, U.S.'),
('WF',N'WALLIS AND FUTUNA'),
('EH',N'WESTERN SAHARA'),
('YE',N'YEMEN'),
('ZM',N'ZAMBIA'),
('ZW',N'ZIMBABWE'),
('XS',N'International')
) CountryData(Short, Country)

SQL

CREATE FUNCTION CheckISIN(@ISIN NVARCHAR(12))
RETURNS INT AS BEGIN
DECLARE @Check INT
--Check Digit not available
IF RIGHT(@ISIN,1) NOT BETWEEN '0' AND '9' BEGIN
 SET @Check=-1
 RETURN @Check
END
--Check country not available
IF (SELECT COUNT(*) FROM SecuritiesIssuer WHERE SecuritiesIssuerShort=LEFT(@ISIN,2))=0 BEGIN
 SET @Check=-2
 RETURN @Check
END
IF PATINDEX('%[^0-Z]%',@ISIN)>0 BEGIN
 SET @Check=-3
 RETURN @Check
END

DECLARE @Data NVARCHAR(30)=LEFT(@ISIN,11)
DECLARE @MultOdd INT= 1, @MultEve INT= 1
DECLARE @Sum INT=0,@StrOdd NVARCHAR(60)='',@StrEve NVARCHAR(60)=''
DECLARE @Letter INT,@Text VARCHAR(1)
SET @Letter =PATINDEX('%[A-Z]%',@Data)


SET @Text=SUBSTRING(@Data,@Letter,1) BEGIN
 WHILE @Letter>0 BEGIN
  SET @Data=STUFF(@Data,@Letter,1,ASCII(UPPER(@Text))-55)
  SET @Letter =PATINDEX('%[A-Z]%',@Data)
  SET @Text=SUBSTRING(@Data,@Letter,1)
 END
END
--Get Length Multiplier
IF LEN(@Data)%2=0 BEGIN
 SET @MultEve = 2;
END
ELSE BEGIN
SET @MultOdd = 2;
SET @Letter = 1;
END

WHILE @Letter<=LEN(@Data) BEGIN
 IF @Letter%2=1 BEGIN
  SET @StrOdd=@StrOdd+CONVERT(VARCHAR(60),CONVERT(INT,SUBSTRING(@Data,@Letter,1))*@MultOdd);
 END 
 ELSE BEGIN
  SET @StrEve=@StrEve+CONVERT(VARCHAR(60),CONVERT(INT,SUBSTRING(@Data,@Letter,1))*@MultEve);
 END
 SET @Letter=@Letter+1
END

SET @Data=@StrOdd+@StrEve
SET @Letter = 1
WHILE @Letter<=LEN(@Data) BEGIN
 SET @Sum=@Sum+CONVERT(INT,SUBSTRING(@Data,@Letter,1))
 SET @Letter=@Letter+1
END
IF LEN(@ISIN)<>12 BEGIN
 SET @Check=-4
 RETURN @Check
END
IF ISNULL(@Check,0)=0 BEGIN
 SET @Check =(SELECT (CASE WHEN RIGHT(@ISIN,1)=CONVERT(VARCHAR(1),(10-(@Sum%10))%10) THEN 1 ELSE 0 END));
END
RETURN @Check
END
GO
SELECT dbo.CheckISIN('US0378331005')
SELECT dbo.CheckISIN('AU0000XVGZA3')
SELECT dbo.CheckISIN('GB0002634946')

Warning!

This will only check the format of the ISIN, not whether it actually exists and is valid.
Check a SEDOL
more: Check SEDOL format with an SQL Function
Check a CUSIP
more: Check CUSIP format with an SQL Function

Author

Was this helpful?

Please note, this commenting system is still in final testing.
Copyright Claytabase Ltd 2020

Registered in England and Wales 08985867

Site Links

RSSLoginLink Cookie PolicySitemap

Social Media

facebook.com/Claytabaseinstagram.com/claytabase/twitter.com/Claytabaselinkedin.com/company/claytabase-ltd

Get in Touch

+442392064871info@claytabase.co.ukClaytabase Ltd, Unit 3d, Rink Road Industrial Estate, PO33 2LT, United Kingdom

Partnered With

The settings on this site are set to allow all cookies. These can be changed on our Cookie Policy & Settings page.
By continuing to use this site you agree to the use of cookies.
Ousia Logo
Logout
Ousia CMS Loader