|
| 1 | +<?php |
| 2 | +require_once 'vendor/base.php'; |
| 3 | + |
| 4 | +function generateTableSchema($table) { |
| 5 | + $schemas = [ |
| 6 | + 'regions' => " |
| 7 | +IF OBJECT_ID('world.regions', 'U') IS NOT NULL DROP TABLE world.regions; |
| 8 | +CREATE TABLE world.regions ( |
| 9 | + id INT IDENTITY(1,1) PRIMARY KEY, |
| 10 | + name NVARCHAR(100) NOT NULL, |
| 11 | + translations NVARCHAR(MAX), |
| 12 | + created_at DATETIME2 NULL, |
| 13 | + updated_at DATETIME2 NOT NULL DEFAULT GETDATE(), |
| 14 | + flag BIT NOT NULL DEFAULT 1, |
| 15 | + wikiDataId NVARCHAR(255) NULL |
| 16 | +);", |
| 17 | + 'subregions' => " |
| 18 | +IF OBJECT_ID('world.subregions', 'U') IS NOT NULL DROP TABLE world.subregions; |
| 19 | +CREATE TABLE world.subregions ( |
| 20 | + id INT IDENTITY(1,1) PRIMARY KEY, |
| 21 | + name NVARCHAR(100) NOT NULL, |
| 22 | + translations NVARCHAR(MAX), |
| 23 | + region_id INT NOT NULL, |
| 24 | + created_at DATETIME2 NULL, |
| 25 | + updated_at DATETIME2 NOT NULL DEFAULT GETDATE(), |
| 26 | + flag BIT NOT NULL DEFAULT 1, |
| 27 | + wikiDataId NVARCHAR(255) NULL, |
| 28 | + CONSTRAINT FK_subregions_regions FOREIGN KEY (region_id) REFERENCES world.regions(id) |
| 29 | +);", |
| 30 | + 'countries' => " |
| 31 | +IF OBJECT_ID('world.countries', 'U') IS NOT NULL DROP TABLE world.countries; |
| 32 | +CREATE TABLE world.countries ( |
| 33 | + id INT IDENTITY(1,1) PRIMARY KEY, |
| 34 | + name NVARCHAR(100) NOT NULL, |
| 35 | + iso3 NCHAR(3) NULL, |
| 36 | + numeric_code NCHAR(3) NULL, |
| 37 | + iso2 NCHAR(2) NULL, |
| 38 | + phonecode NVARCHAR(255) NULL, |
| 39 | + capital NVARCHAR(255) NULL, |
| 40 | + currency NVARCHAR(255) NULL, |
| 41 | + currency_name NVARCHAR(255) NULL, |
| 42 | + currency_symbol NVARCHAR(255) NULL, |
| 43 | + tld NVARCHAR(255) NULL, |
| 44 | + native NVARCHAR(255) NULL, |
| 45 | + region NVARCHAR(255) NULL, |
| 46 | + region_id INT NULL, |
| 47 | + subregion NVARCHAR(255) NULL, |
| 48 | + subregion_id INT NULL, |
| 49 | + nationality NVARCHAR(255) NULL, |
| 50 | + timezones NVARCHAR(MAX), |
| 51 | + translations NVARCHAR(MAX), |
| 52 | + latitude DECIMAL(10,8) NULL, |
| 53 | + longitude DECIMAL(11,8) NULL, |
| 54 | + emoji NVARCHAR(191) NULL, |
| 55 | + emojiU NVARCHAR(191) NULL, |
| 56 | + created_at DATETIME2 NULL, |
| 57 | + updated_at DATETIME2 NOT NULL DEFAULT GETDATE(), |
| 58 | + flag BIT NOT NULL DEFAULT 1, |
| 59 | + wikiDataId NVARCHAR(255) NULL, |
| 60 | + CONSTRAINT FK_countries_regions FOREIGN KEY (region_id) REFERENCES world.regions(id), |
| 61 | + CONSTRAINT FK_countries_subregions FOREIGN KEY (subregion_id) REFERENCES world.subregions(id) |
| 62 | +);", |
| 63 | + 'states' => " |
| 64 | +IF OBJECT_ID('world.states', 'U') IS NOT NULL DROP TABLE world.states; |
| 65 | +CREATE TABLE world.states ( |
| 66 | + id INT IDENTITY(1,1) PRIMARY KEY, |
| 67 | + name NVARCHAR(255) NOT NULL, |
| 68 | + country_id INT NOT NULL, |
| 69 | + country_code NCHAR(2) NOT NULL, |
| 70 | + fips_code NVARCHAR(255) NULL, |
| 71 | + iso2 NVARCHAR(255) NULL, |
| 72 | + type NVARCHAR(191) NULL, |
| 73 | + latitude DECIMAL(10,8) NULL, |
| 74 | + longitude DECIMAL(11,8) NULL, |
| 75 | + created_at DATETIME2 NULL, |
| 76 | + updated_at DATETIME2 NOT NULL DEFAULT GETDATE(), |
| 77 | + flag BIT NOT NULL DEFAULT 1, |
| 78 | + wikiDataId NVARCHAR(255) NULL, |
| 79 | + CONSTRAINT FK_states_countries FOREIGN KEY (country_id) REFERENCES world.countries(id) |
| 80 | +);", |
| 81 | + 'cities' => " |
| 82 | +IF OBJECT_ID('world.cities', 'U') IS NOT NULL DROP TABLE world.cities; |
| 83 | +CREATE TABLE world.cities ( |
| 84 | + id INT IDENTITY(1,1) PRIMARY KEY, |
| 85 | + name NVARCHAR(255) NOT NULL, |
| 86 | + state_id INT NOT NULL, |
| 87 | + state_code NVARCHAR(255) NOT NULL, |
| 88 | + country_id INT NOT NULL, |
| 89 | + country_code NCHAR(2) NOT NULL, |
| 90 | + latitude DECIMAL(10,8) NOT NULL, |
| 91 | + longitude DECIMAL(11,8) NOT NULL, |
| 92 | + created_at DATETIME2 NOT NULL DEFAULT '2014-01-01 12:01:01', |
| 93 | + updated_at DATETIME2 NOT NULL DEFAULT GETDATE(), |
| 94 | + flag BIT NOT NULL DEFAULT 1, |
| 95 | + wikiDataId NVARCHAR(255) NULL, |
| 96 | + CONSTRAINT FK_cities_states FOREIGN KEY (state_id) REFERENCES world.states(id), |
| 97 | + CONSTRAINT FK_cities_countries FOREIGN KEY (country_id) REFERENCES world.countries(id) |
| 98 | +);" |
| 99 | + ]; |
| 100 | + |
| 101 | + return $schemas[$table]; |
| 102 | +} |
| 103 | + |
| 104 | +function generateSqlServerInsert($tableName, $data) { |
| 105 | + $columns = implode(', ', array_keys($data[0])); |
| 106 | + $sql = "INSERT INTO world.$tableName ($columns) VALUES\n"; |
| 107 | + |
| 108 | + foreach ($data as $row) { |
| 109 | + $values = array_map(function($value) { |
| 110 | + if (is_string($value)) { |
| 111 | + return "N'" . str_replace("'", "''", $value) . "'"; |
| 112 | + } elseif ($value === null) { |
| 113 | + return 'NULL'; |
| 114 | + } elseif (is_array($value)) { |
| 115 | + return "N'" . str_replace("'", "''", json_encode($value)) . "'"; |
| 116 | + } else { |
| 117 | + return $value; |
| 118 | + } |
| 119 | + }, $row); |
| 120 | + $sql .= "(" . implode(', ', $values) . "),\n"; |
| 121 | + } |
| 122 | + |
| 123 | + return rtrim($sql, ",\n") . ";\n\n"; |
| 124 | +} |
| 125 | + |
| 126 | +$rootDir = dirname(dirname(__FILE__)); |
| 127 | + |
| 128 | +$tables = ['regions', 'subregions', 'countries', 'states', 'cities']; |
| 129 | + |
| 130 | +// Generate world.sql with schema creation |
| 131 | +$worldSql = " |
| 132 | +-- Create schema if it doesn't exist |
| 133 | +IF NOT EXISTS (SELECT * FROM sys.schemas WHERE name = 'world') |
| 134 | +BEGIN |
| 135 | + EXEC('CREATE SCHEMA world') |
| 136 | +END |
| 137 | +GO |
| 138 | +"; |
| 139 | + |
| 140 | +foreach ($tables as $table) { |
| 141 | + $jsonFile = $rootDir . "/json/$table.json"; |
| 142 | + $sqlFile = $rootDir . "/sqlserver/$table.sql"; |
| 143 | + |
| 144 | + $jsonData = json_decode(file_get_contents($jsonFile), true); |
| 145 | + |
| 146 | + $sql = "-- Table: $table\n\n"; |
| 147 | + $sql .= generateTableSchema($table) . "\n\n"; |
| 148 | + $sql .= "SET IDENTITY_INSERT world.$table ON;\n\n"; |
| 149 | + $sql .= generateSqlServerInsert($table, $jsonData); |
| 150 | + $sql .= "SET IDENTITY_INSERT world.$table OFF;\n\n"; |
| 151 | + |
| 152 | + file_put_contents($sqlFile, $sql); |
| 153 | + |
| 154 | + echo "SQL Server export completed for $table\n"; |
| 155 | + |
| 156 | + // Add to world.sql |
| 157 | + $worldSql .= $sql; |
| 158 | +} |
| 159 | + |
| 160 | +// Save world.sql |
| 161 | +file_put_contents($rootDir . "/sqlserver/world.sql", $worldSql); |
| 162 | + |
| 163 | +echo "All SQL Server exports completed, including world.sql\n"; |
0 commit comments