├── gameplay.png ├── README.md ├── Snake_Control_Pad.sql └── Snake_Installation.sql /gameplay.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/VladislavFurdak/SQLSnakeGame/HEAD/gameplay.png -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # SQL Snake Game 2 | 3 | To intall the game execute **Snake_Installation.sql** on your MS SQL Server instance 4 | To play the game open **Snake_Control_Pad.sql** in MS SQL Server Management Studio and enjoy 5 | ![Gameplay](gameplay.png) 6 | 7 | pshhhhhh 8 | -------------------------------------------------------------------------------- /Snake_Control_Pad.sql: -------------------------------------------------------------------------------- 1 | -- _________ _________ 2 | -- / \ / \ Normand 3 | -- / /~~~~~\ \ / /~~~~~\ \ Veilleux 4 | -- | | | | | | | | 5 | -- | | | | | | | | 6 | -- | | | | | | | | / 7 | -- | | | | | | | | // 8 | --(o o) \ \_____/ / \ \_____/ / 9 | -- \__/ \ / \ / 10 | -- | ~~~~~~~~~ ~~~~~~~~ 11 | -- ^ T-SQL Snake v 1.0 12 | --[ON/OFF] 13 | USE SnakeDB 14 | --Start Pay / Play again----------------- 15 | EXEC Snake.InitGame 'Name' 16 | -------------[CONTROL PAD] --------------| 17 | EXEC Snake.[Go]'W' --| 18 | EXEC Snake.[Go]'A' EXEC Snake.[Go]'D' --| 19 | EXEC Snake.[Go]'S' --| 20 | ------------------------------------------ 21 | --Select a command and press F5 22 | --2016 author: Vladislav Furdak -------------------------------------------------------------------------------- /Snake_Installation.sql: -------------------------------------------------------------------------------- 1 | -- ,'._,`. 2 | -- (-.___.-) 3 | -- (-.___.-) 4 | -- `-.___.-' 5 | -- (( @ @| . __ 6 | -- \ ` | ,\ |`. @| | | _.-._ 7 | -- __`.`=-=mm===mm:: | | |`. | | | ,'=` '=`. 8 | -- ( `-'|:/ /:/ `/ @| | | |, @| @| /---)W(---\ 9 | -- \ \ / / / / @| | ' (----| |----) ,~ 10 | -- |\ \ / /| / / @| \---| |---/ | 11 | -- | \ V /||/ / `.-| |-,' | 12 | -- | `-' |V / \| |/ @' 13 | -- | , |-' __| |__ 14 | -- | .;: _,-. ,--""..| |..""--. 15 | -- ;;:::' " ) (`--::__|_|__::--') 16 | -- ,-" _, / \`--...___...--'/ 17 | --( -:--'/ / /`--...___...--'\ 18 | -- "-._ `"'._/ /`---...___...---'\ 19 | -- "-._ "---. (`---....___....---') 20 | -- .' ",._ ,' ) |`---....___....---'| 21 | -- /`._| `| | (`---....___....---') 22 | -- ( \ | / \`---...___...---'/ 23 | -- `. `, ^"" `:--...___...--;' 24 | -- `.,' hh `-._______.-' 25 | -- T-SQL Snake 1.0 26 | -- Vladislav Furdak 2016 27 | 28 | if db_id('SnakeDB') is not null 29 | begin 30 | use master; 31 | alter database SnakeDB set single_user with rollback immediate 32 | DROP DATABASE SnakeDB 33 | end 34 | 35 | CREATE DATABASE SnakeDB; 36 | use SnakeDB; 37 | IF NOT EXISTS (SELECT * FROM sys.schemas WHERE name = 'Snake') 38 | begin 39 | EXEC('CREATE SCHEMA Snake') 40 | end 41 | GO 42 | 43 | create procedure Snake.CreateField 44 | @width AS int, 45 | @height AS int 46 | AS 47 | begin 48 | SET NOCOUNT ON; 49 | CREATE TABLE Snake.Field 50 | ( 51 | X int NOT NULL , 52 | Y int NOT NULL , 53 | [State] int NOT NULL default(1), 54 | CONSTRAINT CheckCorrectStateCode CHECK ([State] in (1,2,3)), 55 | CONSTRAINT XY_PK PRIMARY KEY (X,Y) 56 | ) 57 | 58 | declare @countW int = 1; 59 | declare @countH int =1; 60 | 61 | while (@countW <= @width) 62 | begin 63 | while (@countH <= @height) 64 | begin 65 | insert into Snake.Field(X,Y,[State]) values(@countW,@countH,1) 66 | set @countH = @countH +1; 67 | end 68 | set @countW = @countW +1; 69 | set @countH = 1; 70 | end 71 | 72 | return; 73 | end 74 | go 75 | 76 | create procedure Snake.CreateScoreTable 77 | as 78 | begin 79 | create table Snake.Score( 80 | Id int IDENTITY(1,1) Primary key, 81 | Name nvarchar(100), 82 | Achived int, 83 | Date datetime2, 84 | IsLost bit DEFAULT(0) 85 | ) 86 | end 87 | go 88 | 89 | create procedure Snake.Initname( 90 | @UserName nvarchar(100), 91 | @UserId int OUT 92 | ) 93 | as 94 | begin 95 | insert into Snake.Score(Name) values(@UserName) 96 | set @UserId = SCOPE_IDENTITY(); 97 | end 98 | go 99 | 100 | create procedure Snake.CreateSnake( 101 | @ScoreId as int, 102 | @StartX as int, 103 | @StartY as int) 104 | as 105 | begin 106 | SET NOCOUNT ON; 107 | create table Snake.Snake( 108 | Id int IDENTITY(1,1) PRIMARY KEY, 109 | X int, 110 | Y int, 111 | IsHead bit DEFAULT(0), 112 | ParentId int NULL, 113 | ScoreId int NOT NULL, 114 | CONSTRAINT HaveParentConstraint FOREIGN KEY(ParentId) REFERENCES Snake.Snake (Id), 115 | CONSTRAINT ScoreIdFK FOREIGN KEY(ScoreId) REFERENCES Snake.Score(Id) 116 | ) 117 | insert into Snake.Snake(x,y,IsHead,ScoreId) values(@StartX,@StartY, 1, @ScoreId) 118 | end 119 | go 120 | 121 | create procedure Snake.RandomX(@output as int OUT) 122 | as 123 | begin 124 | declare @successAttempt bit = 0; 125 | declare @FieldSizeX int = (select max(X) from Snake.Field); 126 | declare @try int = -1; 127 | 128 | while(@successAttempt <> 1) 129 | begin 130 | set @try = (SELECT FLOOR(RAND()*(@FieldSizeX-1)+1)); 131 | set @successAttempt = (select 132 | case when COUNT(*) > 0 then 0 else 1 end 133 | from Snake.Snake s where s.X = @try); 134 | end 135 | set @output = @try; 136 | end 137 | go 138 | 139 | create procedure Snake.RandomY(@output as int OUT) 140 | as 141 | begin 142 | declare @successAttempt bit = 0; 143 | declare @FieldSizeY int = (select max(Y) from Snake.Field); 144 | declare @try int = -1; 145 | 146 | while(@successAttempt <> 1) 147 | begin 148 | set @try = (SELECT FLOOR(RAND()*(@FieldSizeY-1)+1)); 149 | set @successAttempt = (select 150 | case when COUNT(*) > 0 then 0 else 1 end 151 | from Snake.Snake s where s.Y = @try); 152 | end 153 | set @output = @try; 154 | end 155 | go 156 | 157 | create procedure Snake.Lost 158 | as 159 | begin 160 | SET NOCOUNT ON; 161 | declare @lastScore int = (select top(1) Id from Snake.Score order by Id desc) 162 | declare @name nvarchar(100)= (select top(1) Name from Snake.Score order by Id desc) 163 | 164 | declare @score int = (select COUNT(*) from Snake.Snake 165 | where ScoreId = @lastScore) 166 | 167 | update Snake.Score set 168 | IsLost = 1 169 | 170 | PRINT 'Good game, '+@name+' but you lost, your score is '+CAST(@score as nvarchar(max)) 171 | end 172 | go 173 | 174 | create procedure Snake.GenerateAchive 175 | as 176 | begin 177 | declare @achiveX int; 178 | declare @achiveY int; 179 | 180 | EXEC Snake.RandomX @output = @achiveX output 181 | EXEC Snake.RandomY @output = @achiveY output 182 | 183 | update Snake.Field set 184 | [State] = 2 185 | where X = @achiveX and Y = @achiveY; 186 | end 187 | 188 | go 189 | create procedure Snake.RenderField 190 | as 191 | begin 192 | SET NOCOUNT ON; 193 | declare @isLost bit = (select top(1) IsLost from Snake.Score order by Id desc) 194 | if(@isLost = 1) 195 | begin 196 | PRINT 'Please, start new game' 197 | RETURN; 198 | end 199 | 200 | declare @FieldSizeX int = (select max(X) from Snake.Field); 201 | declare @FieldSizeY int = (select max(Y) from Snake.Field); 202 | 203 | declare @countW int = 1; 204 | declare @countH int =1; 205 | 206 | while (@countH <= @FieldSizeY) 207 | begin 208 | declare @line nvarchar(max) = ''; 209 | while (@countW <= @FieldSizeX) 210 | begin 211 | 212 | declare @isSnake int = (select COUNT(*) from Snake.Snake s 213 | where s.X = @countW and s.Y = @countH); 214 | 215 | if(@isSnake <> 0) 216 | begin 217 | set @line = @line + 'S'; 218 | end 219 | else 220 | begin 221 | declare @state nvarchar(1) = (select 222 | (case [State] 223 | when 1 then '`' 224 | when 2 then '*' 225 | end) 226 | From Snake.Field f where f.X = @countW and f.Y = @countH) 227 | set @line = @line + @state; 228 | end 229 | 230 | set @countW = @countW +1; 231 | end 232 | 233 | PRINT @line; 234 | set @countH = @countH +1; 235 | set @countW = 1; 236 | end 237 | 238 | end 239 | go 240 | 241 | create procedure Snake.SetNewSnakeHead( 242 | @newX as int, 243 | @newY as int 244 | ) 245 | as 246 | begin 247 | SET NOCOUNT ON; 248 | BEGIN TRY 249 | BEGIN TRANSACTION 250 | 251 | declare @oldHeadId int = (select Id from Snake.Snake where IsHead = 1) -- get old head id 252 | declare @oldScoreId int = (select ScoreId from Snake.Snake where IsHead = 1) 253 | 254 | update Snake.Snake set IsHead = 0 -- remove head 255 | 256 | insert into Snake.Snake (X,Y,IsHead,ParentId,ScoreId) --insert new heaed item 257 | values(@newX, @newY, 1, null,@oldScoreId) 258 | 259 | declare @newSnakeHeadId int = SCOPE_IDENTITY(); -- new head id 260 | 261 | update Snake.Snake set ParentId = @newSnakeHeadId -- add relation to new head 262 | where Id = @oldHeadId 263 | END TRY 264 | BEGIN CATCH 265 | if @@TRANCOUNT > 0 266 | rollback transaction; 267 | END CATCH 268 | 269 | if @@TRANCOUNT > 0 270 | commit; 271 | end 272 | go 273 | 274 | create procedure Snake.MoveHead( 275 | @newX as int, 276 | @newY as int 277 | ) 278 | as 279 | begin 280 | --move snake 281 | With SnakeCTE(SnakeId, snakeX, snakeY, snakeIsHead, PointLevel) 282 | AS 283 | ( 284 | select s.Id as SnakeId,X as snakeX,Y as snakeY ,IsHead as snakeY ,1 as PointLevel from Snake.Snake s 285 | where s.IsHead = 1 286 | UNION ALL 287 | select s.Id as SnakeId,X as snakeX,Y as snakeY ,IsHead as snakeY ,PointLevel - 1 as PointLevel from Snake.Snake s 288 | JOIN SnakeCTE AS sCTE ON s.ParentId = sCTE.SnakeId 289 | ) 290 | update Snake.Snake 291 | SET 292 | X = CTE2.snakeX, 293 | Y = CTE2.snakeY 294 | FROM Snake.Snake AS s 295 | JOIN SnakeCTE AS sCTE ON s.Id = sCTE.SnakeId 296 | JOIN SnakeCTE as CTE2 ON CTE2.PointLevel = sCTE.PointLevel + 1 297 | 298 | --set new head 299 | update Snake.Snake set 300 | X = @newX, 301 | Y = @newY 302 | where IsHead = 1 303 | end 304 | go 305 | 306 | create procedure Snake.[Go] 307 | @Direction as nvarchar(1) --W,A,S,D 308 | as 309 | begin 310 | SET NOCOUNT ON; 311 | set @Direction = lower(@Direction); 312 | 313 | if( @Direction <> 'w' and 314 | @Direction <> 'a' and 315 | @Direction <> 's' and 316 | @Direction <> 'd') 317 | RETURN; 318 | 319 | declare @deltaX int = isnull((select 320 | case @Direction 321 | when 'a' then -1 322 | when 'd' then 1 323 | end 324 | ),0) 325 | 326 | declare @deltaY int = isnull((select 327 | case @Direction 328 | when 'w' then -1 329 | when 's' then 1 330 | end 331 | ),0) 332 | 333 | declare @headX int = (select X from Snake.Snake where IsHead = 1); 334 | declare @headY int = (select Y from Snake.Snake where IsHead = 1); 335 | declare @FieldSizeX int = (select max(X) from Snake.Field); 336 | declare @FieldSizeY int = (select max(Y) from Snake.Field); 337 | declare @NewX int = @headX + @deltaX; 338 | declare @NewY int = @headY + @deltaY; 339 | 340 | if( 341 | (@NewX NOT BETWEEN 1 AND @FieldSizeX ) OR 342 | (@NewY NOT BETWEEN 1 AND @FieldSizeY) OR 343 | (select Count(*) from Snake.Snake where X =@NewX and Y = @NewY and IsHead = 0) > 0 344 | ) 345 | begin 346 | exec Snake.Lost; 347 | return; 348 | end 349 | 350 | 351 | declare @newPositionState int = 352 | (select [State] from Snake.Field f 353 | where 354 | f.X = @NewX and 355 | f.Y = @NewY) 356 | 357 | if(@newPositionState = 2) --achive detected 358 | begin 359 | update Snake.Field set [State] = 1 where X = @NewX and Y = @NewY -- remove achive 360 | EXEC Snake.SetNewSnakeHead @newX = @NewX, @newY = @NewY 361 | EXEC Snake.GenerateAchive --add stuff 362 | end 363 | else 364 | begin 365 | EXEC Snake.MoveHead @newX = @NewX, @newY = @NewY 366 | end 367 | --end logic begin render 368 | EXEC Snake.RenderField; 369 | END 370 | go 371 | 372 | create procedure Snake.ClearGame 373 | as 374 | begin 375 | SET NOCOUNT ON; 376 | IF OBJECT_ID('Snake.Snake', 'U') IS NOT NULL 377 | DROP TABLE Snake.Snake; 378 | 379 | IF OBJECT_ID('Snake.Score', 'U') IS NOT NULL 380 | DROP TABLE Snake.Score; 381 | 382 | IF OBJECT_ID('Snake.Field', 'U') IS NOT NULL 383 | DROP TABLE Snake.Field; 384 | end 385 | go 386 | 387 | -- Let me move faster ! 388 | -- ____ 389 | -- / . .\ 390 | --MT \ ---< 391 | -- \ / 392 | -- __________/ / 393 | ---=:___________/ 394 | create procedure Snake.CreateIndexes 395 | as 396 | begin 397 | CREATE NONCLUSTERED INDEX SnakeFieldX ON Snake.Field (X); 398 | CREATE NONCLUSTERED INDEX SnakeFieldY ON Snake.Field (Y); 399 | CREATE NONCLUSTERED INDEX SnakeFieldXY ON Snake.Field (X, Y); 400 | 401 | CREATE NONCLUSTERED INDEX SnakeSnakeX ON Snake.Snake (X); 402 | CREATE NONCLUSTERED INDEX SnakeSnakeY ON Snake.Snake (Y); 403 | CREATE NONCLUSTERED INDEX SnakeSnakeXY ON Snake.Snake (X, Y); 404 | end 405 | go 406 | 407 | create procedure Snake.InitGame 408 | ( 409 | @playerName nvarchar(max) 410 | ) 411 | as 412 | begin 413 | SET NOCOUNT ON; 414 | declare @ScoreId int; 415 | 416 | EXEC Snake.ClearGame 417 | EXEC Snake.CreateScoreTable 418 | EXEC Snake.InitName @playerName, @UserId = @ScoreId out 419 | EXEC Snake.CreateField @width = 15, @height = 15 420 | EXEC Snake.CreateSnake @ScoreId, @StartX = 7, @StartY = 7 421 | EXEC Snake.CreateIndexes 422 | EXEC Snake.GenerateAchive 423 | EXEC Snake.RenderField 424 | end 425 | --------------------------------------------------------------------------------